Transaction control in procedures

Started by Peter Eisentrautabout 8 years ago41 messages
#1Peter Eisentraut
peter.eisentraut@2ndquadrant.com
1 attachment(s)

Here is a patch that implements transaction control in PL/Python
procedures. (This patch goes on top of "SQL procedures" patch v1.)

So you can do this:

CREATE PROCEDURE transaction_test1()
LANGUAGE plpythonu
AS $$
for i in range(0, 10):
plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
if i % 2 == 0:
plpy.commit()
else:
plpy.rollback()
$$;

CALL transaction_test1();

I started with PL/Python because the internal structures there are more
manageable. Obviously, people will want this for PL/pgSQL as well, and
I have that in the works. It's not in a usable state, but I have found
that the work needed is essentially the same as in PL/Python for example.

I have discovered three groups of obstacles that needed addressing to
make this work. At this point, the patch is more of a demo of what
these issues are, and if we come to satisfactory solutions for each of
them, things should fall into place more easily afterwards.

1) While calling CommitTransactionCommand() in the middle of a utility
command works just fine (several utility commands do this, of course),
calling AbortCurrentTransaction() in a similar way does not. There are
a few pieces of code that think that a transaction abort will always
result in a return to the main control loop, and so they will just clean
away everything. This is what the changes in portalmem.c are about.
Some comments there already hint about the issue. No doubt this will
need further refinement. I think it would be desirable in general to
separate the control flow concerns from the transaction management
concerns more cleanly.

2) SPI needs some work. It thinks that it can clean everything away at
transaction end. I have found that instead of TopTransactionContext one
can use PortalContext and get a more suitable life cycle for the memory.
I have played with some variants to make this configurable (e.g.,
argument to SPI_connect()), but that didn't seem very useful. There are
some comments indicating that there might not always be a PortalContext,
but the existing tests don't seem to mind. (There was a thread recently
about making a fake PortalContext for autovacuum, so maybe the current
idea is that we make sure there always is a PortalContext.) Maybe we
need another context like StatementContext or ProcedureContext.

There also needs to be a way via SPI to end transactions and allowing
*some* cleanup to happen but leaving the memory around. I have done
that via additional SPI API functions like SPI_commit(), which are then
available to PL implementations. I also tried making it possible
calling transaction statements directly via SPI_exec() or similar, but
that ended up a total disaster. So from the API perspective, I like the
current implementation, but the details will no doubt need refinement.

3) The PL implementations themselves allocate memory in
transaction-bound contexts for convenience as well. This is usually
easy to fix by switching to PortalContext as well. As you see, the
PL/Python code part of the patch is actually very small. Changes in
other PLs would be similar.

Two issues have not been addressed yet:

A) It would be desirable to be able to run commands such as VACUUM and
CREATE INDEX CONCURRENTLY in a procedure. This needs a bit of thinking
and standards-lawyering about the semantics, like where exactly do
transactions begin and end in various combinations. It will probably
also need a different entry point into SPI, because SPI_exec cannot
handle statements ending transactions. But so far my assessment is that
this can be added in a mostly independent way later on.

B) There needs to be some kind of call stack for procedure and function
invocations, so that we can track when we are allowed to make
transaction controlling calls. The key term in the SQL standard is
"non-atomic execution context", which seems specifically devised to
cover this scenario. So for example, if you have CALL -> CALL -> CALL,
the third call can issue a transaction statement. But if you have CALL
-> SELECT -> CALL, then the last call cannot, because the SELECT
introduces an atomic execution context. I don't know if we have such a
thing yet or something that we could easily latch on to.

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

Attachments:

v1-0001-Transaction-control-in-PL-Python-procedures.patchtext/plain; charset=UTF-8; name=v1-0001-Transaction-control-in-PL-Python-procedures.patch; x-mac-creator=0; x-mac-type=0Download
From 1b3318154540d0fe71480ca58938433ecfccabbd Mon Sep 17 00:00:00 2001
From: Peter Eisentraut <peter_e@gmx.net>
Date: Tue, 31 Oct 2017 14:48:51 -0400
Subject: [PATCH v1] Transaction control in PL/Python procedures

Add .commit, .rollback, and .start_transaction functions to plpy module
to control transactions in a PL/Python function.  Add similar underlying
functions to SPI.  Some additional cleanup so that transaction commit or
abort doesn't blow away data structures still used by the procedure
call.
---
 src/backend/commands/functioncmds.c               |  3 +
 src/backend/executor/spi.c                        | 71 +++++++++++++++++------
 src/backend/utils/mmgr/portalmem.c                | 39 +++++--------
 src/include/executor/spi.h                        |  4 ++
 src/include/executor/spi_priv.h                   |  1 +
 src/pl/plpython/Makefile                          |  1 +
 src/pl/plpython/expected/plpython_test.out        |  9 ++-
 src/pl/plpython/expected/plpython_transaction.out | 44 ++++++++++++++
 src/pl/plpython/plpy_main.c                       |  2 +-
 src/pl/plpython/plpy_plpymodule.c                 | 38 ++++++++++++
 src/pl/plpython/sql/plpython_transaction.sql      | 36 ++++++++++++
 11 files changed, 201 insertions(+), 47 deletions(-)
 create mode 100644 src/pl/plpython/expected/plpython_transaction.out
 create mode 100644 src/pl/plpython/sql/plpython_transaction.sql

diff --git a/src/backend/commands/functioncmds.c b/src/backend/commands/functioncmds.c
index 1f3156d870..badef78fdf 100644
--- a/src/backend/commands/functioncmds.c
+++ b/src/backend/commands/functioncmds.c
@@ -65,6 +65,7 @@
 #include "utils/fmgroids.h"
 #include "utils/guc.h"
 #include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/rel.h"
 #include "utils/syscache.h"
 #include "utils/tqual.h"
@@ -2255,6 +2256,8 @@ ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
 							   FUNC_MAX_ARGS,
 							   FUNC_MAX_ARGS)));
 
+	MemoryContextSwitchTo(PortalContext);
+
 	fmgr_info(fexpr->funcid, &flinfo);
 	InitFunctionCallInfoData(fcinfo, &flinfo, nargs, fexpr->inputcollid, NULL, NULL);
 
diff --git a/src/backend/executor/spi.c b/src/backend/executor/spi.c
index 40292b86c1..f097f15731 100644
--- a/src/backend/executor/spi.c
+++ b/src/backend/executor/spi.c
@@ -92,7 +92,7 @@ SPI_connect(void)
 			elog(ERROR, "SPI stack corrupted");
 		newdepth = 16;
 		_SPI_stack = (_SPI_connection *)
-			MemoryContextAlloc(TopTransactionContext,
+			MemoryContextAlloc(TopMemoryContext,
 							   newdepth * sizeof(_SPI_connection));
 		_SPI_stack_depth = newdepth;
 	}
@@ -133,10 +133,10 @@ SPI_connect(void)
 	 * Perhaps CurTransactionContext would do?	For now it doesn't matter
 	 * because we clean up explicitly in AtEOSubXact_SPI().
 	 */
-	_SPI_current->procCxt = AllocSetContextCreate(TopTransactionContext,
+	_SPI_current->procCxt = AllocSetContextCreate(PortalContext,
 												  "SPI Proc",
 												  ALLOCSET_DEFAULT_SIZES);
-	_SPI_current->execCxt = AllocSetContextCreate(TopTransactionContext,
+	_SPI_current->execCxt = AllocSetContextCreate(_SPI_current->procCxt,
 												  "SPI Exec",
 												  ALLOCSET_DEFAULT_SIZES);
 	/* ... and switch to procedure's context */
@@ -158,8 +158,6 @@ SPI_finish(void)
 	MemoryContextSwitchTo(_SPI_current->savedcxt);
 
 	/* Release memory used in procedure call (including tuptables) */
-	MemoryContextDelete(_SPI_current->execCxt);
-	_SPI_current->execCxt = NULL;
 	MemoryContextDelete(_SPI_current->procCxt);
 	_SPI_current->procCxt = NULL;
 
@@ -181,12 +179,58 @@ SPI_finish(void)
 	return SPI_OK_FINISH;
 }
 
+int
+SPI_start_transaction(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	StartTransactionCommand();
+	MemoryContextSwitchTo(oldcontext);
+	return 0;
+}
+
+
+int
+SPI_commit(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	_SPI_current->internal_xact = true;
+
+	if (ActiveSnapshotSet())
+		PopActiveSnapshot();
+	CommitTransactionCommand();
+	MemoryContextSwitchTo(oldcontext);
+
+	_SPI_current->internal_xact = false;
+
+	return 0;
+}
+
+int
+SPI_rollback(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	_SPI_current->internal_xact = true;
+
+	AbortCurrentTransaction();
+	MemoryContextSwitchTo(oldcontext);
+
+	_SPI_current->internal_xact = false;
+
+	return 0;
+}
+
 /*
  * Clean up SPI state at transaction commit or abort.
  */
 void
 AtEOXact_SPI(bool isCommit)
 {
+	if (_SPI_current && _SPI_current->internal_xact)
+		return;
+
 	/*
 	 * Note that memory contexts belonging to SPI stack entries will be freed
 	 * automatically, so we can ignore them here.  We just need to restore our
@@ -224,21 +268,10 @@ AtEOSubXact_SPI(bool isCommit, SubTransactionId mySubid)
 		if (connection->connectSubid != mySubid)
 			break;				/* couldn't be any underneath it either */
 
-		found = true;
+		if (connection->internal_xact)
+			break;
 
-		/*
-		 * Release procedure memory explicitly (see note in SPI_connect)
-		 */
-		if (connection->execCxt)
-		{
-			MemoryContextDelete(connection->execCxt);
-			connection->execCxt = NULL;
-		}
-		if (connection->procCxt)
-		{
-			MemoryContextDelete(connection->procCxt);
-			connection->procCxt = NULL;
-		}
+		found = true;
 
 		/*
 		 * Pop the stack entry and reset global variables.  Unlike
diff --git a/src/backend/utils/mmgr/portalmem.c b/src/backend/utils/mmgr/portalmem.c
index 89db08464f..d07dc060a5 100644
--- a/src/backend/utils/mmgr/portalmem.c
+++ b/src/backend/utils/mmgr/portalmem.c
@@ -736,11 +736,8 @@ PreCommit_Portals(bool isPrepare)
 /*
  * Abort processing for portals.
  *
- * At this point we reset "active" status and run the cleanup hook if
- * present, but we can't release the portal's memory until the cleanup call.
- *
- * The reason we need to reset active is so that we can replace the unnamed
- * portal, else we'll fail to execute ROLLBACK when it arrives.
+ * At this point we run the cleanup hook if present, but we can't release the
+ * portal's memory until the cleanup call.
  */
 void
 AtAbort_Portals(void)
@@ -754,17 +751,6 @@ AtAbort_Portals(void)
 	{
 		Portal		portal = hentry->portal;
 
-		/*
-		 * See similar code in AtSubAbort_Portals().  This would fire if code
-		 * orchestrating multiple top-level transactions within a portal, such
-		 * as VACUUM, caught errors and continued under the same portal with a
-		 * fresh transaction.  No part of core PostgreSQL functions that way.
-		 * XXX Such code would wish the portal to remain ACTIVE, as in
-		 * PreCommit_Portals().
-		 */
-		if (portal->status == PORTAL_ACTIVE)
-			MarkPortalFailed(portal);
-
 		/*
 		 * Do nothing else to cursors held over from a previous transaction.
 		 */
@@ -799,14 +785,6 @@ AtAbort_Portals(void)
 		 * PortalDrop.
 		 */
 		portal->resowner = NULL;
-
-		/*
-		 * Although we can't delete the portal data structure proper, we can
-		 * release any memory in subsidiary contexts, such as executor state.
-		 * The cleanup hook was the last thing that might have needed data
-		 * there.
-		 */
-		MemoryContextDeleteChildren(PortalGetHeapMemory(portal));
 	}
 }
 
@@ -826,6 +804,19 @@ AtCleanup_Portals(void)
 	{
 		Portal		portal = hentry->portal;
 
+		/*
+		 * Do not touch active portals --- this can only happen in the case of
+		 * a multi-transaction command.
+		 *
+		 * Note however that any resource owner attached to such a portal is
+		 * still going to go away, so don't leave a dangling pointer.
+		 */
+		if (portal->status == PORTAL_ACTIVE)
+		{
+			portal->resowner = NULL;
+			continue;
+		}
+
 		/* Do nothing to cursors held over from a previous transaction */
 		if (portal->createSubid == InvalidSubTransactionId)
 		{
diff --git a/src/include/executor/spi.h b/src/include/executor/spi.h
index acade7e92e..1bf73d8594 100644
--- a/src/include/executor/spi.h
+++ b/src/include/executor/spi.h
@@ -156,6 +156,10 @@ extern int	SPI_register_relation(EphemeralNamedRelation enr);
 extern int	SPI_unregister_relation(const char *name);
 extern int	SPI_register_trigger_data(TriggerData *tdata);
 
+extern int	SPI_start_transaction(void);
+extern int	SPI_commit(void);
+extern int	SPI_rollback(void);
+
 extern void AtEOXact_SPI(bool isCommit);
 extern void AtEOSubXact_SPI(bool isCommit, SubTransactionId mySubid);
 
diff --git a/src/include/executor/spi_priv.h b/src/include/executor/spi_priv.h
index 8fae755418..c12a465712 100644
--- a/src/include/executor/spi_priv.h
+++ b/src/include/executor/spi_priv.h
@@ -36,6 +36,7 @@ typedef struct
 	MemoryContext savedcxt;		/* context of SPI_connect's caller */
 	SubTransactionId connectSubid;	/* ID of connecting subtransaction */
 	QueryEnvironment *queryEnv; /* query environment setup for SPI level */
+	bool		internal_xact;	/* SPI-managed transaction boundary, skip cleanup */
 } _SPI_connection;
 
 /*
diff --git a/src/pl/plpython/Makefile b/src/pl/plpython/Makefile
index cc91afebde..d09910835d 100644
--- a/src/pl/plpython/Makefile
+++ b/src/pl/plpython/Makefile
@@ -90,6 +90,7 @@ REGRESS = \
 	plpython_quote \
 	plpython_composite \
 	plpython_subtransaction \
+	plpython_transaction \
 	plpython_drop
 
 REGRESS_PLPYTHON3_MANGLE := $(REGRESS)
diff --git a/src/pl/plpython/expected/plpython_test.out b/src/pl/plpython/expected/plpython_test.out
index 847e4cc412..f0a10cc05f 100644
--- a/src/pl/plpython/expected/plpython_test.out
+++ b/src/pl/plpython/expected/plpython_test.out
@@ -43,11 +43,12 @@ contents.sort()
 return contents
 $$ LANGUAGE plpythonu;
 select module_contents();
- module_contents 
------------------
+  module_contents  
+-------------------
  Error
  Fatal
  SPIError
+ commit
  cursor
  debug
  error
@@ -60,10 +61,12 @@ select module_contents();
  quote_ident
  quote_literal
  quote_nullable
+ rollback
  spiexceptions
+ start_transaction
  subtransaction
  warning
-(18 rows)
+(21 rows)
 
 CREATE FUNCTION elog_test_basic() RETURNS void
 AS $$
diff --git a/src/pl/plpython/expected/plpython_transaction.out b/src/pl/plpython/expected/plpython_transaction.out
new file mode 100644
index 0000000000..64e3abdd60
--- /dev/null
+++ b/src/pl/plpython/expected/plpython_transaction.out
@@ -0,0 +1,44 @@
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+         plpy.commit()
+    else:
+         plpy.rollback()
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+DO
+LANGUAGE plpythonu
+$$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+         plpy.commit()
+    else:
+         plpy.rollback()
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+DROP TABLE test1;
diff --git a/src/pl/plpython/plpy_main.c b/src/pl/plpython/plpy_main.c
index 7df50c09c8..0d3b4a8fbc 100644
--- a/src/pl/plpython/plpy_main.c
+++ b/src/pl/plpython/plpy_main.c
@@ -424,7 +424,7 @@ PLy_push_execution_context(void)
 	PLyExecutionContext *context;
 
 	context = (PLyExecutionContext *)
-		MemoryContextAlloc(TopTransactionContext, sizeof(PLyExecutionContext));
+		MemoryContextAlloc(PortalContext, sizeof(PLyExecutionContext));
 	context->curr_proc = NULL;
 	context->scratch_ctx = NULL;
 	context->next = PLy_execution_contexts;
diff --git a/src/pl/plpython/plpy_plpymodule.c b/src/pl/plpython/plpy_plpymodule.c
index 759ad44932..a95e66bfee 100644
--- a/src/pl/plpython/plpy_plpymodule.c
+++ b/src/pl/plpython/plpy_plpymodule.c
@@ -6,8 +6,10 @@
 
 #include "postgres.h"
 
+#include "access/xact.h"
 #include "mb/pg_wchar.h"
 #include "utils/builtins.h"
+#include "utils/snapmgr.h"
 
 #include "plpython.h"
 
@@ -41,6 +43,9 @@ static PyObject *PLy_fatal(PyObject *self, PyObject *args, PyObject *kw);
 static PyObject *PLy_quote_literal(PyObject *self, PyObject *args);
 static PyObject *PLy_quote_nullable(PyObject *self, PyObject *args);
 static PyObject *PLy_quote_ident(PyObject *self, PyObject *args);
+static PyObject *PLy_start_transaction(PyObject *self, PyObject *args);
+static PyObject *PLy_commit(PyObject *self, PyObject *args);
+static PyObject *PLy_rollback(PyObject *self, PyObject *args);
 
 
 /* A list of all known exceptions, generated from backend/utils/errcodes.txt */
@@ -95,6 +100,13 @@ static PyMethodDef PLy_methods[] = {
 	 */
 	{"cursor", PLy_cursor, METH_VARARGS, NULL},
 
+	/*
+	 * transaction control
+	 */
+	{"start_transaction", PLy_start_transaction, METH_NOARGS, NULL},
+	{"commit", PLy_commit, METH_NOARGS, NULL},
+	{"rollback", PLy_rollback, METH_NOARGS, NULL},
+
 	{NULL, NULL, 0, NULL}
 };
 
@@ -577,3 +589,29 @@ PLy_output(volatile int level, PyObject *self, PyObject *args, PyObject *kw)
 	 */
 	Py_RETURN_NONE;
 }
+
+static PyObject *
+PLy_start_transaction(PyObject *self, PyObject *args)
+{
+	SPI_start_transaction();
+
+	Py_RETURN_NONE;
+}
+
+static PyObject *
+PLy_commit(PyObject *self, PyObject *args)
+{
+	SPI_commit();
+	SPI_start_transaction();
+
+	Py_RETURN_NONE;
+}
+
+static PyObject *
+PLy_rollback(PyObject *self, PyObject *args)
+{
+	SPI_rollback();
+	SPI_start_transaction();
+
+	Py_RETURN_NONE;
+}
diff --git a/src/pl/plpython/sql/plpython_transaction.sql b/src/pl/plpython/sql/plpython_transaction.sql
new file mode 100644
index 0000000000..42f191b008
--- /dev/null
+++ b/src/pl/plpython/sql/plpython_transaction.sql
@@ -0,0 +1,36 @@
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+         plpy.commit()
+    else:
+         plpy.rollback()
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+DO
+LANGUAGE plpythonu
+$$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+         plpy.commit()
+    else:
+         plpy.rollback()
+$$;
+
+SELECT * FROM test1;
+
+
+DROP TABLE test1;

base-commit: ee4673ac071f8352c41cc673299b7ec695f079ff
prerequisite-patch-id: 7b37b5c8905dcab64b9c6b8f98caf81049a569ec
-- 
2.14.3

#2Simon Riggs
simon@2ndquadrant.com
In reply to: Peter Eisentraut (#1)
Re: Transaction control in procedures

On 31 October 2017 at 15:38, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

Here is a patch that implements transaction control in PL/Python
procedures. (This patch goes on top of "SQL procedures" patch v1.)

The patch is incredibly short for such a feature, which is probably a
good indication that it is feasible.

Amazing!

So you can do this:

CREATE PROCEDURE transaction_test1()
LANGUAGE plpythonu
AS $$
for i in range(0, 10):
plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
if i % 2 == 0:
plpy.commit()
else:
plpy.rollback()
$$;

CALL transaction_test1();

I started with PL/Python because the internal structures there are more
manageable.

AFAICS we execute 10 INSERTs and each one runs in a new top-level xid.
The INSERTs succeed in all cases but we then abort odd-numbered ones
and commit even numbered ones.

What would happen if some of the INSERTs failed? Where would control
go to? (Maybe this is just "no change" in this particular proc)

What happens if the procedure is updated during execution? Presumably
it keeps executing the original version as seen in the initial
snapshot?

Does the xmin of this session advance after each transaction, or do we
hold the snapshot used for the procedure body open, causing us to hold
back xmin and prevent vacuuming from being effective?

What would happen if a procedure recursively called itself? And yet it
was updated half-way through? Would that throw an error (I think it
should).

Obviously, people will want this for PL/pgSQL as well, and
I have that in the works. It's not in a usable state, but I have found
that the work needed is essentially the same as in PL/Python for example.

I have discovered three groups of obstacles that needed addressing to
make this work. At this point, the patch is more of a demo of what
these issues are, and if we come to satisfactory solutions for each of
them, things should fall into place more easily afterwards.

1) While calling CommitTransactionCommand() in the middle of a utility
command works just fine (several utility commands do this, of course),
calling AbortCurrentTransaction() in a similar way does not. There are
a few pieces of code that think that a transaction abort will always
result in a return to the main control loop, and so they will just clean
away everything. This is what the changes in portalmem.c are about.
Some comments there already hint about the issue. No doubt this will
need further refinement. I think it would be desirable in general to
separate the control flow concerns from the transaction management
concerns more cleanly.

+1

2) SPI needs some work. It thinks that it can clean everything away at
transaction end. I have found that instead of TopTransactionContext one
can use PortalContext and get a more suitable life cycle for the memory.
I have played with some variants to make this configurable (e.g.,
argument to SPI_connect()), but that didn't seem very useful. There are
some comments indicating that there might not always be a PortalContext,
but the existing tests don't seem to mind. (There was a thread recently
about making a fake PortalContext for autovacuum, so maybe the current
idea is that we make sure there always is a PortalContext.) Maybe we
need another context like StatementContext or ProcedureContext.

There also needs to be a way via SPI to end transactions and allowing
*some* cleanup to happen but leaving the memory around. I have done
that via additional SPI API functions like SPI_commit(), which are then
available to PL implementations. I also tried making it possible
calling transaction statements directly via SPI_exec() or similar, but
that ended up a total disaster. So from the API perspective, I like the
current implementation, but the details will no doubt need refinement.

3) The PL implementations themselves allocate memory in
transaction-bound contexts for convenience as well. This is usually
easy to fix by switching to PortalContext as well. As you see, the
PL/Python code part of the patch is actually very small. Changes in
other PLs would be similar.

Is there some kind of interlock to prevent dropping the portal half way thru?

Will the SPI transaction control functions fail if called from a
normal function?

Two issues have not been addressed yet:

A) It would be desirable to be able to run commands such as VACUUM and
CREATE INDEX CONCURRENTLY in a procedure. This needs a bit of thinking
and standards-lawyering about the semantics, like where exactly do
transactions begin and end in various combinations. It will probably
also need a different entry point into SPI, because SPI_exec cannot
handle statements ending transactions. But so far my assessment is that
this can be added in a mostly independent way later on.

Sounds like a separate commit, but perhaps it influences the design?

B) There needs to be some kind of call stack for procedure and function
invocations, so that we can track when we are allowed to make
transaction controlling calls. The key term in the SQL standard is
"non-atomic execution context", which seems specifically devised to
cover this scenario. So for example, if you have CALL -> CALL -> CALL,
the third call can issue a transaction statement. But if you have CALL
-> SELECT -> CALL, then the last call cannot, because the SELECT
introduces an atomic execution context. I don't know if we have such a
thing yet or something that we could easily latch on to.

Yeh. The internal_xact flag is only set at EoXact, so its not really
set as described in the .h
It would certainly be useful to have some state that allows sanity
checking on weird state transitions.

What we would benefit from is a README that gives the theory of
operation, so everyone can read and agree.

Presumably we would need to contact authors of main PL languages to
get them to comment on the API requirements for their languages.

--
Simon Riggs http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

--
Sent via pgsql-hackers mailing list (pgsql-hackers@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-hackers

#3Merlin Moncure
mmoncure@gmail.com
In reply to: Simon Riggs (#2)
Re: [HACKERS] Transaction control in procedures

On Wed, Nov 8, 2017 at 5:48 PM, Simon Riggs <simon@2ndquadrant.com> wrote:

On 31 October 2017 at 15:38, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

Here is a patch that implements transaction control in PL/Python
procedures. (This patch goes on top of "SQL procedures" patch v1.)

The patch is incredibly short for such a feature, which is probably a
good indication that it is feasible.

Amazing!

I have to agree with that. I'm really excited about this...

Some questions:
*) Will it be possible to do operations like this in pl/pgsql?

BEGIN
SELECT INTO r * FROM foo;

START TRANSACTION; -- perhaps we ought to have a special function
for this instead (BEGIN is reserved, etc).
SET transaction_isololation TO serializable;
...

*) Will there be any negative consequences to a procedure running
with an unbounded run time? For example, something like:

LOOP
SELECT check_for_stuff_to_do();

IF stuff_to_do
THEN
do_stuff();
ELSE
PERFORM pg_sleep(1);
END IF;
END LOOP;

*) Will pg_cancel_backend() cancel the currently executing statement
or the procedure? (I guess probably the procedure but I'm curious)

*) Will long running procedures be subject to statement timeout (and
does it apply to the entire procedure)? Will they be able to control
statement_timeout from within the procedure itself?

*) Will pg_stat_activity show the invoking CALL or the currently
executing statement? I see a strong argument for showing both of
these things. although I understand that's out of scope here.

If these questions (especially the first two) come down the correct
way, then it will mean that I can stop coding in other languages
(primarily bash) for a fairly large number of cases that I really
think belong in the database itself. This would really simplify
coding, some things in bash are really awkward to get right such as a
mutex to guarantee single script invocation. My only real dependency
on the operation system environment at that point would be cron to
step in to the backround daemon process (which would immediately set
an advisory lock).

I'm somewhat surprised that SPI is the point of attack for this
functionality, but if it works that's really the best case scenario
(the only downside I can see is that the various out of core pl/s have
to implement the interface individually).

merlin

#4Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: Merlin Moncure (#3)
Re: [HACKERS] Transaction control in procedures

On 11/14/17 09:27, Merlin Moncure wrote:

*) Will it be possible to do operations like this in pl/pgsql?

BEGIN
SELECT INTO r * FROM foo;

START TRANSACTION; -- perhaps we ought to have a special function
for this instead (BEGIN is reserved, etc).
SET transaction_isololation TO serializable;
...

Eventually, I don't see why not. Currently, it's not complete.

One detail in your example is that when you enter the procedure, you are
already in a transaction, so you would have to run either COMMIT or
ROLLBACK before the START TRANSACTION.

Also, you can't run SET TRANSACTION ISOLATION through SPI, so one would
have to implement a separate code path for that, but that would just be
a bit of leg work.

*) Will there be any negative consequences to a procedure running
with an unbounded run time? For example, something like:

LOOP
SELECT check_for_stuff_to_do();

IF stuff_to_do
THEN
do_stuff();
ELSE
PERFORM pg_sleep(1);
END IF;
END LOOP;

That procedure doesn't do anything with transactions, so it's just like
a long-running function. Otherwise, it'd just be like long-running
client code managing transactions.

*) Will pg_cancel_backend() cancel the currently executing statement
or the procedure? (I guess probably the procedure but I'm curious)

Same as the way it currently works. It will raise an exception, which
will travel up the stack and eventually issue an error or be caught. If
someone knows more specific concerns here I could look into it, but I
don't see any problem.

*) Will long running procedures be subject to statement timeout (and
does it apply to the entire procedure)?

See previous item.

Will they be able to control
statement_timeout from within the procedure itself?

The statement timeout alarm is set by the top-level execution loop, so
you can't change a statement timeout that is already in progress. But
you could change the GUC and commit it for the next top-level statement.

*) Will pg_stat_activity show the invoking CALL or the currently
executing statement? I see a strong argument for showing both of
these things. although I understand that's out of scope here.

Not different from a function execution, i.e., top-level statement.

If these questions (especially the first two) come down the correct
way, then it will mean that I can stop coding in other languages
(primarily bash) for a fairly large number of cases that I really
think belong in the database itself. This would really simplify
coding, some things in bash are really awkward to get right such as a
mutex to guarantee single script invocation. My only real dependency
on the operation system environment at that point would be cron to
step in to the backround daemon process (which would immediately set
an advisory lock).

Well, some kind of scheduler around procedures would be pretty cool at
some point.

I'm somewhat surprised that SPI is the point of attack for this
functionality, but if it works that's really the best case scenario
(the only downside I can see is that the various out of core pl/s have
to implement the interface individually).

So I tried different things here, and I'll list them here to explain how
I got there.

Option zero is to not use SPI at all and implement a whole new internal
command execution system. But that would obviously be a large amount of
work, and it would look 85% like SPI, and as it turns out it's not
necessary.

The first thing I tried out what to run transaction control statements
through SPI. That turned out to be very complicated and confusing and
fragile, mainly because of the dichotomy between the internal
subtransaction management that the PLs do and the explicit transaction
control statements on the other hand. It was just a giant unworkable mess.

The next thing I tried was to shut down (SPI_finish) SPI before a
transaction boundary command and restart it (SPI_connect) it afterwards.
That would work in principle, but it would require a fair amount of
work in each PL, because they implicitly rely on SPI (or perhaps are
tangled up with SPI) for memory management.

The setup I finally arrived at was to implement the transaction boundary
commands as SPI API calls and let them internally make sure that only
the appropriate stuff is cleared away at transaction boundaries. This
turned out to be the easiest and cleanest. I have since the last patch
implemented the transaction control capabilities in PL/pgSQL, PL/Perl,
and PL/Tcl, and it was entirely trivial once the details were worked out
as I had shown in PL/Python. I will post an updated patch with this soon.

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#5Merlin Moncure
mmoncure@gmail.com
In reply to: Peter Eisentraut (#4)
Re: [HACKERS] Transaction control in procedures

On Tue, Nov 14, 2017 at 12:09 PM, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

On 11/14/17 09:27, Merlin Moncure wrote:

*) Will it be possible to do operations like this in pl/pgsql?

BEGIN
SELECT INTO r * FROM foo;

START TRANSACTION; -- perhaps we ought to have a special function
for this instead (BEGIN is reserved, etc).
SET transaction_isololation TO serializable;
...

Eventually, I don't see why not. Currently, it's not complete.

One detail in your example is that when you enter the procedure, you are
already in a transaction, so you would have to run either COMMIT or
ROLLBACK before the START TRANSACTION.

Ok, that's good, but it seems a little wonky to me to have to issue
COMMIT first. Shouldn't that be the default? Meaning you would not
be *in* a transaction unless you specified to be in one.

Also, you can't run SET TRANSACTION ISOLATION through SPI, so one would
have to implement a separate code path for that, but that would just be
a bit of leg work.

Roger -- I'm more interested in if your design generally supports this
being able to this (either now or in the future...). I'm hammering on
this point for basically two reasons:

1) Trying to understand if the MVCC snapshot creation can be
meaningfully controlled (I think so, but I'll verify)).
2) This is an important case for databases that want to run in a mode
(typically serializeable) but lower the isolation for specific cases;
for example to loop on a special flag being set in a table. It's
annoying to only be able to specify this on the client side; I tend to
like to abstract arcane database considerations into the database
whenever possible.

*) Will there be any negative consequences to a procedure running
with an unbounded run time? For example, something like:

LOOP
SELECT check_for_stuff_to_do();

IF stuff_to_do
THEN
do_stuff();
ELSE
PERFORM pg_sleep(1);
END IF;
END LOOP;

That procedure doesn't do anything with transactions, so it's just like
a long-running function. Otherwise, it'd just be like long-running
client code managing transactions.

Can we zero in on this? The question implied, 'can you do this
without being in a transaction'? PERFORM do_stuff() is a implicit
transaction, so it ought to end when the function returns right?
Meaning, assuming I was not already in a transaction when hitting this
block, I would not be subject to an endless transaction duration?

*) Will pg_cancel_backend() cancel the currently executing statement

or the procedure? (I guess probably the procedure but I'm curious)

Same as the way it currently works. It will raise an exception, which
will travel up the stack and eventually issue an error or be caught. If
someone knows more specific concerns here I could look into it, but I
don't see any problem.

Yeah, that works.

I'm somewhat surprised that SPI is the point of attack for this
functionality, but if it works that's really the best case scenario
(the only downside I can see is that the various out of core pl/s have
to implement the interface individually).

So I tried different things here, and I'll list them here to explain how
I got there.

Option zero is to not use SPI at all and implement a whole new internal
command execution system. But that would obviously be a large amount of
work, and it would look 85% like SPI, and as it turns out it's not
necessary.

The first thing I tried out what to run transaction control statements
through SPI. That turned out to be very complicated and confusing and
fragile, mainly because of the dichotomy between the internal
subtransaction management that the PLs do and the explicit transaction
control statements on the other hand. It was just a giant unworkable mess.

The next thing I tried was to shut down (SPI_finish) SPI before a
transaction boundary command and restart it (SPI_connect) it afterwards.
That would work in principle, but it would require a fair amount of
work in each PL, because they implicitly rely on SPI (or perhaps are
tangled up with SPI) for memory management.

The setup I finally arrived at was to implement the transaction boundary
commands as SPI API calls and let them internally make sure that only
the appropriate stuff is cleared away at transaction boundaries. This
turned out to be the easiest and cleanest. I have since the last patch
implemented the transaction control capabilities in PL/pgSQL, PL/Perl,
and PL/Tcl, and it was entirely trivial once the details were worked out
as I had shown in PL/Python. I will post an updated patch with this soon.

well, you've convinced me. now that you've got pl/pgsql implemented
I'll fire it up and see if I can make qualitative assessments...

merlin

#6legrand legrand
legrand_legrand@hotmail.com
In reply to: Merlin Moncure (#5)
Re: Transaction control in procedures

will that kind of statement (that is permitted with Oracle but gives errors
ora-1555 snapshot too old) be permitted ?

begin
for c in (select id from tab where cond='blabla')
loop
update tab set x=1 where id=c.id;
commit;
end loop;
end;

--
Sent from: http://www.postgresql-archive.org/PostgreSQL-hackers-f1928748.html

#7Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: Merlin Moncure (#5)
Re: [HACKERS] Transaction control in procedures

On 11/14/17 16:33, Merlin Moncure wrote:

One detail in your example is that when you enter the procedure, you are
already in a transaction, so you would have to run either COMMIT or
ROLLBACK before the START TRANSACTION.

Ok, that's good, but it seems a little wonky to me to have to issue
COMMIT first. Shouldn't that be the default? Meaning you would not
be *in* a transaction unless you specified to be in one.

But that's not how this feature is defined in the SQL standard and AFAIK
other implementations. When you enter the procedure call, you are in a
transaction. For one thing, a procedure does not *have* to do
transaction control. So if it's a plain old procedure like a function
that just runs a few statements, there needs to be a transaction. We
can't know ahead of time whether the procedure will execute a
transaction control statement and then retroactively change when the
transaction should have started. Something like an autonomous
transaction procedure might work more like that, but not this feature.

Also, you can't run SET TRANSACTION ISOLATION through SPI, so one would
have to implement a separate code path for that, but that would just be
a bit of leg work.

Roger -- I'm more interested in if your design generally supports this
being able to this (either now or in the future...).

Nothing in this patch really changes anything about how transactions
themselves work. So I don't see why any of this shouldn't work. As I
fill in the gaps in the code, I'll make sure to come back around to
this, but for the time being I can't say anything more.

Can we zero in on this? The question implied, 'can you do this
without being in a transaction'? PERFORM do_stuff() is a implicit
transaction, so it ought to end when the function returns right?
Meaning, assuming I was not already in a transaction when hitting this
block, I would not be subject to an endless transaction duration?

In the server, you are always in a transaction, so that's not how this
works. I think this also ties into my first response above.

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#8Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: Peter Eisentraut (#1)
1 attachment(s)
Re: [HACKERS] Transaction control in procedures

On 10/31/17 15:38, Peter Eisentraut wrote:

Here is a patch that implements transaction control in PL/Python
procedures. (This patch goes on top of "SQL procedures" patch v1.)

Here is an updated patch, now on top of "SQL procedures" v2.

Relative to the previous patch v1 I added transaction control to
PL/pgSQL, PL/Perl, and PL/Tcl with relative ease. (There is a weird
crash in one PL/Perl test that is currently commented out. And I can't
get a proper backtrace. Maybe something to do with recursive Perl
interpreters?)

I crash-coursed myself in PL/Perl and PL/Tcl (and Tcl). If anyone has
more of a feel for those languages and wants to comment on the proposed
interfaces and internals, please chime in.

I also added tracking so that transaction control commands can only be
made in the proper context, currently meaning only top-level procedure
calls, not functions or other procedure calls. This should be extended
to also allow nested CALLs without anything in between, but I need more
time to code that.

I'll spend a bit more time on tidying up a few things, and a bunch of
documentation is missing, but I currently don't see any more major
issues here.

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

Attachments:

v2-0001-Transaction-control-in-PL-procedures.patchtext/plain; charset=UTF-8; name=v2-0001-Transaction-control-in-PL-procedures.patch; x-mac-creator=0; x-mac-type=0Download
From 522c8f20ddcb3f670b0a5687bdc4c7b18d5eaeae Mon Sep 17 00:00:00 2001
From: Peter Eisentraut <peter_e@gmx.net>
Date: Tue, 14 Nov 2017 18:00:26 -0500
Subject: [PATCH v2] Transaction control in PL procedures

In each of the supplied procedural languages (PL/pgSQL, PL/Perl,
PL/Python, PL/Tcl), add language-specific commit and rollback
functions/commands to control transactions in procedures in that
language.  Add similar underlying functions to SPI.  Some additional
cleanup so that transaction commit or abort doesn't blow away data
structures still used by the procedure call.  Add execution context
tracking to CALL statement so that transaction control commands can only
be issued in top-level procedure calls, not function calls or other
procedure calls.
---
 src/backend/commands/functioncmds.c               | 29 ++++++-
 src/backend/executor/spi.c                        | 93 +++++++++++++++++-----
 src/backend/tcop/utility.c                        |  2 +-
 src/backend/utils/mmgr/portalmem.c                | 39 ++++-----
 src/include/commands/defrem.h                     | 12 ++-
 src/include/executor/spi.h                        |  5 ++
 src/include/executor/spi_priv.h                   |  4 +
 src/include/nodes/nodes.h                         |  3 +-
 src/pl/plperl/GNUmakefile                         |  2 +-
 src/pl/plperl/SPI.xs                              | 12 +++
 src/pl/plperl/expected/plperl_transaction.out     | 85 ++++++++++++++++++++
 src/pl/plperl/plperl.c                            |  6 ++
 src/pl/plperl/sql/plperl_transaction.sql          | 76 ++++++++++++++++++
 src/pl/plpgsql/src/pl_exec.c                      | 48 +++++++++++-
 src/pl/plpgsql/src/pl_funcs.c                     | 44 +++++++++++
 src/pl/plpgsql/src/pl_gram.y                      | 34 ++++++++
 src/pl/plpgsql/src/pl_handler.c                   |  8 ++
 src/pl/plpgsql/src/pl_scanner.c                   |  2 +
 src/pl/plpgsql/src/plpgsql.h                      | 22 +++++-
 src/pl/plpython/Makefile                          |  1 +
 src/pl/plpython/expected/plpython_test.out        |  9 ++-
 src/pl/plpython/expected/plpython_transaction.out | 83 ++++++++++++++++++++
 src/pl/plpython/plpy_main.c                       |  7 +-
 src/pl/plpython/plpy_plpymodule.c                 | 38 +++++++++
 src/pl/plpython/sql/plpython_transaction.sql      | 69 ++++++++++++++++
 src/pl/tcl/Makefile                               |  2 +-
 src/pl/tcl/expected/pltcl_transaction.out         | 63 +++++++++++++++
 src/pl/tcl/pltcl.c                                | 45 +++++++++++
 src/pl/tcl/sql/pltcl_transaction.sql              | 60 ++++++++++++++
 src/test/regress/expected/plpgsql.out             | 96 +++++++++++++++++++++++
 src/test/regress/sql/plpgsql.sql                  | 82 +++++++++++++++++++
 31 files changed, 1025 insertions(+), 56 deletions(-)
 create mode 100644 src/pl/plperl/expected/plperl_transaction.out
 create mode 100644 src/pl/plperl/sql/plperl_transaction.sql
 create mode 100644 src/pl/plpython/expected/plpython_transaction.out
 create mode 100644 src/pl/plpython/sql/plpython_transaction.sql
 create mode 100644 src/pl/tcl/expected/pltcl_transaction.out
 create mode 100644 src/pl/tcl/sql/pltcl_transaction.sql

diff --git a/src/backend/commands/functioncmds.c b/src/backend/commands/functioncmds.c
index 1f3156d870..263f3a69c4 100644
--- a/src/backend/commands/functioncmds.c
+++ b/src/backend/commands/functioncmds.c
@@ -65,6 +65,7 @@
 #include "utils/fmgroids.h"
 #include "utils/guc.h"
 #include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/rel.h"
 #include "utils/syscache.h"
 #include "utils/tqual.h"
@@ -2207,9 +2208,28 @@ ExecuteDoStmt(DoStmt *stmt)
 
 /*
  * Execute CALL statement
+ *
+ * Inside a top-level CALL statement, transaction-terminating commands such as
+ * COMMIT or a PL-specific equivalent are allowed.  The terminology in the SQL
+ * standard is that CALL establishes a non-atomic execution context.  Most
+ * other commands establish an atomic execution context, in which transaction
+ * control actions are not allowed.  If there are nested executions of CALL,
+ * we want to track the execution context recursively, so that the nested
+ * CALLs can also do transaction control.  Note, however, that for example in
+ * CALL -> SELECT -> CALL, the second call cannot do transaction control,
+ * because the SELECT in between establishes an atomic execution context.
+ *
+ * So when ExecuteCallStmt() is called from the top level, we pass in atomic =
+ * false (recall that that means transactions = yes).  We then create a
+ * CallContext node with content atomic = false, which is passed in the
+ * fcinfo->context field to the procedure invocation.  The language
+ * implementation should then take appropriate measures to allow or prevent
+ * transaction commands based on that information, e.g., call
+ * SPI_set_nonatomic().  The language should also pass on the atomic flag to
+ * any recursive invocations to CALL.
  */
 void
-ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
+ExecuteCallStmt(ParseState *pstate, CallStmt *stmt, bool atomic)
 {
 	List	   *targs;
 	ListCell   *lc;
@@ -2220,6 +2240,7 @@ ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
 	AclResult   aclresult;
 	FmgrInfo	flinfo;
 	FunctionCallInfoData fcinfo;
+	CallContext *callcontext;
 
 	targs = NIL;
 	foreach(lc, stmt->funccall->args)
@@ -2255,8 +2276,12 @@ ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
 							   FUNC_MAX_ARGS,
 							   FUNC_MAX_ARGS)));
 
+	MemoryContextSwitchTo(PortalContext);
+
+	callcontext = makeNode(CallContext);
+	callcontext->atomic = atomic;
 	fmgr_info(fexpr->funcid, &flinfo);
-	InitFunctionCallInfoData(fcinfo, &flinfo, nargs, fexpr->inputcollid, NULL, NULL);
+	InitFunctionCallInfoData(fcinfo, &flinfo, nargs, fexpr->inputcollid, (Node *) callcontext, NULL);
 
 	i = 0;
 	foreach (lc, fexpr->args)
diff --git a/src/backend/executor/spi.c b/src/backend/executor/spi.c
index 2da1cac3e2..7d47a90638 100644
--- a/src/backend/executor/spi.c
+++ b/src/backend/executor/spi.c
@@ -92,7 +92,7 @@ SPI_connect(void)
 			elog(ERROR, "SPI stack corrupted");
 		newdepth = 16;
 		_SPI_stack = (_SPI_connection *)
-			MemoryContextAlloc(TopTransactionContext,
+			MemoryContextAlloc(TopMemoryContext,
 							   newdepth * sizeof(_SPI_connection));
 		_SPI_stack_depth = newdepth;
 	}
@@ -124,6 +124,7 @@ SPI_connect(void)
 	_SPI_current->execCxt = NULL;
 	_SPI_current->connectSubid = GetCurrentSubTransactionId();
 	_SPI_current->queryEnv = NULL;
+	_SPI_current->atomic = true;	/* until told otherwise */
 
 	/*
 	 * Create memory contexts for this procedure
@@ -133,10 +134,10 @@ SPI_connect(void)
 	 * Perhaps CurTransactionContext would do?	For now it doesn't matter
 	 * because we clean up explicitly in AtEOSubXact_SPI().
 	 */
-	_SPI_current->procCxt = AllocSetContextCreate(TopTransactionContext,
+	_SPI_current->procCxt = AllocSetContextCreate(PortalContext,
 												  "SPI Proc",
 												  ALLOCSET_DEFAULT_SIZES);
-	_SPI_current->execCxt = AllocSetContextCreate(TopTransactionContext,
+	_SPI_current->execCxt = AllocSetContextCreate(_SPI_current->procCxt,
 												  "SPI Exec",
 												  ALLOCSET_DEFAULT_SIZES);
 	/* ... and switch to procedure's context */
@@ -145,6 +146,17 @@ SPI_connect(void)
 	return SPI_OK_CONNECT;
 }
 
+int
+SPI_set_nonatomic(void)
+{
+	if (_SPI_current == NULL)
+		return SPI_ERROR_UNCONNECTED;
+
+	_SPI_current->atomic = false;
+
+	return SPI_OK_CONNECT;
+}
+
 int
 SPI_finish(void)
 {
@@ -158,8 +170,6 @@ SPI_finish(void)
 	MemoryContextSwitchTo(_SPI_current->savedcxt);
 
 	/* Release memory used in procedure call (including tuptables) */
-	MemoryContextDelete(_SPI_current->execCxt);
-	_SPI_current->execCxt = NULL;
 	MemoryContextDelete(_SPI_current->procCxt);
 	_SPI_current->procCxt = NULL;
 
@@ -181,12 +191,68 @@ SPI_finish(void)
 	return SPI_OK_FINISH;
 }
 
+int
+SPI_start_transaction(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	StartTransactionCommand();
+	MemoryContextSwitchTo(oldcontext);
+	return 0;
+}
+
+
+int
+SPI_commit(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	if (_SPI_current->atomic)
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("invalid transaction termination")));
+
+	_SPI_current->internal_xact = true;
+
+	if (ActiveSnapshotSet())
+		PopActiveSnapshot();
+	CommitTransactionCommand();
+	MemoryContextSwitchTo(oldcontext);
+
+	_SPI_current->internal_xact = false;
+
+	return 0;
+}
+
+int
+SPI_rollback(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	if (_SPI_current->atomic)
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("invalid transaction termination")));
+
+	_SPI_current->internal_xact = true;
+
+	AbortCurrentTransaction();
+	MemoryContextSwitchTo(oldcontext);
+
+	_SPI_current->internal_xact = false;
+
+	return 0;
+}
+
 /*
  * Clean up SPI state at transaction commit or abort.
  */
 void
 AtEOXact_SPI(bool isCommit)
 {
+	if (_SPI_current && _SPI_current->internal_xact)
+		return;
+
 	/*
 	 * Note that memory contexts belonging to SPI stack entries will be freed
 	 * automatically, so we can ignore them here.  We just need to restore our
@@ -224,21 +290,10 @@ AtEOSubXact_SPI(bool isCommit, SubTransactionId mySubid)
 		if (connection->connectSubid != mySubid)
 			break;				/* couldn't be any underneath it either */
 
-		found = true;
+		if (connection->internal_xact)
+			break;
 
-		/*
-		 * Release procedure memory explicitly (see note in SPI_connect)
-		 */
-		if (connection->execCxt)
-		{
-			MemoryContextDelete(connection->execCxt);
-			connection->execCxt = NULL;
-		}
-		if (connection->procCxt)
-		{
-			MemoryContextDelete(connection->procCxt);
-			connection->procCxt = NULL;
-		}
+		found = true;
 
 		/*
 		 * Pop the stack entry and reset global variables.  Unlike
diff --git a/src/backend/tcop/utility.c b/src/backend/tcop/utility.c
index 4da1f8f643..1e8de07e11 100644
--- a/src/backend/tcop/utility.c
+++ b/src/backend/tcop/utility.c
@@ -658,7 +658,7 @@ standard_ProcessUtility(PlannedStmt *pstmt,
 			break;
 
 		case T_CallStmt:
-			ExecuteCallStmt(pstate, castNode(CallStmt, parsetree));
+			ExecuteCallStmt(pstate, castNode(CallStmt, parsetree), context != PROCESS_UTILITY_TOPLEVEL);
 			break;
 
 		case T_ClusterStmt:
diff --git a/src/backend/utils/mmgr/portalmem.c b/src/backend/utils/mmgr/portalmem.c
index d03b779407..1b217c312a 100644
--- a/src/backend/utils/mmgr/portalmem.c
+++ b/src/backend/utils/mmgr/portalmem.c
@@ -736,11 +736,8 @@ PreCommit_Portals(bool isPrepare)
 /*
  * Abort processing for portals.
  *
- * At this point we reset "active" status and run the cleanup hook if
- * present, but we can't release the portal's memory until the cleanup call.
- *
- * The reason we need to reset active is so that we can replace the unnamed
- * portal, else we'll fail to execute ROLLBACK when it arrives.
+ * At this point we run the cleanup hook if present, but we can't release the
+ * portal's memory until the cleanup call.
  */
 void
 AtAbort_Portals(void)
@@ -754,17 +751,6 @@ AtAbort_Portals(void)
 	{
 		Portal		portal = hentry->portal;
 
-		/*
-		 * See similar code in AtSubAbort_Portals().  This would fire if code
-		 * orchestrating multiple top-level transactions within a portal, such
-		 * as VACUUM, caught errors and continued under the same portal with a
-		 * fresh transaction.  No part of core PostgreSQL functions that way.
-		 * XXX Such code would wish the portal to remain ACTIVE, as in
-		 * PreCommit_Portals().
-		 */
-		if (portal->status == PORTAL_ACTIVE)
-			MarkPortalFailed(portal);
-
 		/*
 		 * Do nothing else to cursors held over from a previous transaction.
 		 */
@@ -799,14 +785,6 @@ AtAbort_Portals(void)
 		 * PortalDrop.
 		 */
 		portal->resowner = NULL;
-
-		/*
-		 * Although we can't delete the portal data structure proper, we can
-		 * release any memory in subsidiary contexts, such as executor state.
-		 * The cleanup hook was the last thing that might have needed data
-		 * there.
-		 */
-		MemoryContextDeleteChildren(PortalGetHeapMemory(portal));
 	}
 }
 
@@ -826,6 +804,19 @@ AtCleanup_Portals(void)
 	{
 		Portal		portal = hentry->portal;
 
+		/*
+		 * Do not touch active portals --- this can only happen in the case of
+		 * a multi-transaction command.
+		 *
+		 * Note however that any resource owner attached to such a portal is
+		 * still going to go away, so don't leave a dangling pointer.
+		 */
+		if (portal->status == PORTAL_ACTIVE)
+		{
+			portal->resowner = NULL;
+			continue;
+		}
+
 		/* Do nothing to cursors held over from a previous transaction */
 		if (portal->createSubid == InvalidSubTransactionId)
 		{
diff --git a/src/include/commands/defrem.h b/src/include/commands/defrem.h
index 52cbf61ccb..8ebe3c48aa 100644
--- a/src/include/commands/defrem.h
+++ b/src/include/commands/defrem.h
@@ -59,7 +59,7 @@ extern void DropTransformById(Oid transformOid);
 extern void IsThereFunctionInNamespace(const char *proname, int pronargs,
 						   oidvector *proargtypes, Oid nspOid);
 extern void ExecuteDoStmt(DoStmt *stmt);
-extern void ExecuteCallStmt(ParseState *pstate, CallStmt *stmt);
+extern void ExecuteCallStmt(ParseState *pstate, CallStmt *stmt, bool atomic);
 extern Oid	get_cast_oid(Oid sourcetypeid, Oid targettypeid, bool missing_ok);
 extern Oid	get_transform_oid(Oid type_id, Oid lang_id, bool missing_ok);
 extern void interpret_function_parameter_list(ParseState *pstate,
@@ -74,6 +74,16 @@ extern void interpret_function_parameter_list(ParseState *pstate,
 								  Oid *variadicArgType,
 								  Oid *requiredResultType);
 
+/*
+ * Procedure call context information
+ */
+typedef struct CallContext
+{
+	NodeTag		type;
+	bool		atomic;
+} CallContext;
+
+
 /* commands/operatorcmds.c */
 extern ObjectAddress DefineOperator(List *names, List *parameters);
 extern void RemoveOperatorById(Oid operOid);
diff --git a/src/include/executor/spi.h b/src/include/executor/spi.h
index acade7e92e..e38158c54e 100644
--- a/src/include/executor/spi.h
+++ b/src/include/executor/spi.h
@@ -78,6 +78,7 @@ extern PGDLLIMPORT SPITupleTable *SPI_tuptable;
 extern PGDLLIMPORT int SPI_result;
 
 extern int	SPI_connect(void);
+extern int	SPI_set_nonatomic(void);
 extern int	SPI_finish(void);
 extern int	SPI_execute(const char *src, bool read_only, long tcount);
 extern int SPI_execute_plan(SPIPlanPtr plan, Datum *Values, const char *Nulls,
@@ -156,6 +157,10 @@ extern int	SPI_register_relation(EphemeralNamedRelation enr);
 extern int	SPI_unregister_relation(const char *name);
 extern int	SPI_register_trigger_data(TriggerData *tdata);
 
+extern int	SPI_start_transaction(void);
+extern int	SPI_commit(void);
+extern int	SPI_rollback(void);
+
 extern void AtEOXact_SPI(bool isCommit);
 extern void AtEOSubXact_SPI(bool isCommit, SubTransactionId mySubid);
 
diff --git a/src/include/executor/spi_priv.h b/src/include/executor/spi_priv.h
index 8fae755418..9dc8af22e4 100644
--- a/src/include/executor/spi_priv.h
+++ b/src/include/executor/spi_priv.h
@@ -36,6 +36,10 @@ typedef struct
 	MemoryContext savedcxt;		/* context of SPI_connect's caller */
 	SubTransactionId connectSubid;	/* ID of connecting subtransaction */
 	QueryEnvironment *queryEnv; /* query environment setup for SPI level */
+
+	/* transaction management support */
+	bool		atomic;			/* atomic execution context, does not allow transactions */
+	bool		internal_xact;	/* SPI-managed transaction boundary, skip cleanup */
 } _SPI_connection;
 
 /*
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 43ee88bd39..82dbf4e177 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -499,7 +499,8 @@ typedef enum NodeTag
 	T_FdwRoutine,				/* in foreign/fdwapi.h */
 	T_IndexAmRoutine,			/* in access/amapi.h */
 	T_TsmRoutine,				/* in access/tsmapi.h */
-	T_ForeignKeyCacheInfo		/* in utils/rel.h */
+	T_ForeignKeyCacheInfo,		/* in utils/rel.h */
+	T_CallContext				/* in commands/defrem.h */
 } NodeTag;
 
 /*
diff --git a/src/pl/plperl/GNUmakefile b/src/pl/plperl/GNUmakefile
index b829027d05..933abb47c4 100644
--- a/src/pl/plperl/GNUmakefile
+++ b/src/pl/plperl/GNUmakefile
@@ -55,7 +55,7 @@ endif # win32
 SHLIB_LINK = $(perl_embed_ldflags)
 
 REGRESS_OPTS = --dbname=$(PL_TESTDB) --load-extension=plperl  --load-extension=plperlu
-REGRESS = plperl plperl_lc plperl_trigger plperl_shared plperl_elog plperl_util plperl_init plperlu plperl_array plperl_call
+REGRESS = plperl plperl_lc plperl_trigger plperl_shared plperl_elog plperl_util plperl_init plperlu plperl_array plperl_call plperl_transaction
 # if Perl can support two interpreters in one backend,
 # test plperl-and-plperlu cases
 ifneq ($(PERL),)
diff --git a/src/pl/plperl/SPI.xs b/src/pl/plperl/SPI.xs
index d9e6f579d4..dc9ddedc8f 100644
--- a/src/pl/plperl/SPI.xs
+++ b/src/pl/plperl/SPI.xs
@@ -17,6 +17,7 @@
 #define PG_NEED_PERL_XSUB_H
 #include "plperl.h"
 #include "plperl_helpers.h"
+#include "executor/spi.h"
 
 
 MODULE = PostgreSQL::InServer::SPI PREFIX = spi_
@@ -152,6 +153,17 @@ spi_spi_cursor_close(sv)
 		plperl_spi_cursor_close(cursor);
 		pfree(cursor);
 
+void
+spi_spi_commit()
+	CODE:
+		SPI_commit();
+		SPI_start_transaction();
+
+void
+spi_spi_rollback()
+	CODE:
+		SPI_rollback();
+		SPI_start_transaction();
 
 BOOT:
     items = 0;  /* avoid 'unused variable' warning */
diff --git a/src/pl/plperl/expected/plperl_transaction.out b/src/pl/plperl/expected/plperl_transaction.out
new file mode 100644
index 0000000000..38e9651d3e
--- /dev/null
+++ b/src/pl/plperl/expected/plperl_transaction.out
@@ -0,0 +1,85 @@
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+DO
+LANGUAGE plperl
+$$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+return 1;
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/Perl function "transaction_test2"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query("CALL transaction_test1()");
+return 1;
+$$;
+-- FIXME
+--SELECT transaction_test3();
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+DROP TABLE test1;
diff --git a/src/pl/plperl/plperl.c b/src/pl/plperl/plperl.c
index 9f5313235f..f3133e816b 100644
--- a/src/pl/plperl/plperl.c
+++ b/src/pl/plperl/plperl.c
@@ -23,6 +23,7 @@
 #include "catalog/pg_proc.h"
 #include "catalog/pg_proc_fn.h"
 #include "catalog/pg_type.h"
+#include "commands/defrem.h"
 #include "commands/event_trigger.h"
 #include "commands/trigger.h"
 #include "executor/spi.h"
@@ -1931,6 +1932,7 @@ plperl_inline_handler(PG_FUNCTION_ARGS)
 
 		if (SPI_connect() != SPI_OK_CONNECT)
 			elog(ERROR, "could not connect to SPI manager");
+		SPI_set_nonatomic();
 
 		select_perl_context(desc.lanpltrusted);
 
@@ -2409,6 +2411,10 @@ plperl_func_handler(PG_FUNCTION_ARGS)
 	current_call_data->prodesc = prodesc;
 	increment_prodesc_refcount(prodesc);
 
+	if (prodesc->result_oid == InvalidOid &&
+		!castNode(CallContext, fcinfo->context)->atomic)
+		SPI_set_nonatomic();
+
 	/* Set a callback for error reporting */
 	pl_error_context.callback = plperl_exec_callback;
 	pl_error_context.previous = error_context_stack;
diff --git a/src/pl/plperl/sql/plperl_transaction.sql b/src/pl/plperl/sql/plperl_transaction.sql
new file mode 100644
index 0000000000..864a3e396c
--- /dev/null
+++ b/src/pl/plperl/sql/plperl_transaction.sql
@@ -0,0 +1,76 @@
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+DO
+LANGUAGE plperl
+$$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+return 1;
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query("CALL transaction_test1()");
+return 1;
+$$;
+
+-- FIXME
+--SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+DROP TABLE test1;
diff --git a/src/pl/plpgsql/src/pl_exec.c b/src/pl/plpgsql/src/pl_exec.c
index 882b16e2b1..2943618d62 100644
--- a/src/pl/plpgsql/src/pl_exec.c
+++ b/src/pl/plpgsql/src/pl_exec.c
@@ -215,6 +215,10 @@ static int exec_stmt_dynexecute(PLpgSQL_execstate *estate,
 					 PLpgSQL_stmt_dynexecute *stmt);
 static int exec_stmt_dynfors(PLpgSQL_execstate *estate,
 				  PLpgSQL_stmt_dynfors *stmt);
+static int exec_stmt_commit(PLpgSQL_execstate *estate,
+				PLpgSQL_stmt_commit *stmt);
+static int exec_stmt_rollback(PLpgSQL_execstate *estate,
+				PLpgSQL_stmt_rollback *stmt);
 
 static void plpgsql_estate_setup(PLpgSQL_execstate *estate,
 					 PLpgSQL_function *func,
@@ -1652,6 +1656,14 @@ exec_stmt(PLpgSQL_execstate *estate, PLpgSQL_stmt *stmt)
 			rc = exec_stmt_close(estate, (PLpgSQL_stmt_close *) stmt);
 			break;
 
+		case PLPGSQL_STMT_COMMIT:
+			rc = exec_stmt_commit(estate, (PLpgSQL_stmt_commit *) stmt);
+			break;
+
+		case PLPGSQL_STMT_ROLLBACK:
+			rc = exec_stmt_rollback(estate, (PLpgSQL_stmt_rollback *) stmt);
+			break;
+
 		default:
 			estate->err_stmt = save_estmt;
 			elog(ERROR, "unrecognized cmdtype: %d", stmt->cmd_type);
@@ -4356,6 +4368,39 @@ exec_stmt_close(PLpgSQL_execstate *estate, PLpgSQL_stmt_close *stmt)
 	return PLPGSQL_RC_OK;
 }
 
+/*
+ * exec_stmt_commit
+ *
+ * Commit the transaction.
+ */
+static int
+exec_stmt_commit(PLpgSQL_execstate *estate, PLpgSQL_stmt_commit *stmt)
+{
+	SPI_commit();
+	SPI_start_transaction();
+
+	estate->simple_eval_estate = NULL;
+	plpgsql_create_econtext(estate);
+
+	return PLPGSQL_RC_OK;
+}
+
+/*
+ * exec_stmt_rollback
+ *
+ * Abort the transaction.
+ */
+static int
+exec_stmt_rollback(PLpgSQL_execstate *estate, PLpgSQL_stmt_rollback *stmt)
+{
+	SPI_rollback();
+	SPI_start_transaction();
+
+	estate->simple_eval_estate = NULL;
+	plpgsql_create_econtext(estate);
+
+	return PLPGSQL_RC_OK;
+}
 
 /* ----------
  * exec_assign_expr			Put an expression's result into a variable.
@@ -6858,7 +6903,8 @@ plpgsql_xact_cb(XactEvent event, void *arg)
 	if (event == XACT_EVENT_COMMIT || event == XACT_EVENT_PREPARE)
 	{
 		/* Shouldn't be any econtext stack entries left at commit */
-		Assert(simple_econtext_stack == NULL);
+		//Assert(simple_econtext_stack == NULL);
+		simple_econtext_stack = NULL;
 
 		if (shared_simple_eval_estate)
 			FreeExecutorState(shared_simple_eval_estate);
diff --git a/src/pl/plpgsql/src/pl_funcs.c b/src/pl/plpgsql/src/pl_funcs.c
index 23f54e1c21..a3a45916d1 100644
--- a/src/pl/plpgsql/src/pl_funcs.c
+++ b/src/pl/plpgsql/src/pl_funcs.c
@@ -284,6 +284,10 @@ plpgsql_stmt_typename(PLpgSQL_stmt *stmt)
 			return "CLOSE";
 		case PLPGSQL_STMT_PERFORM:
 			return "PERFORM";
+		case PLPGSQL_STMT_COMMIT:
+			return "COMMIT";
+		case PLPGSQL_STMT_ROLLBACK:
+			return "ROLLBACK";
 	}
 
 	return "unknown";
@@ -363,6 +367,8 @@ static void free_open(PLpgSQL_stmt_open *stmt);
 static void free_fetch(PLpgSQL_stmt_fetch *stmt);
 static void free_close(PLpgSQL_stmt_close *stmt);
 static void free_perform(PLpgSQL_stmt_perform *stmt);
+static void free_commit(PLpgSQL_stmt_commit *stmt);
+static void free_rollback(PLpgSQL_stmt_rollback *stmt);
 static void free_expr(PLpgSQL_expr *expr);
 
 
@@ -443,6 +449,12 @@ free_stmt(PLpgSQL_stmt *stmt)
 		case PLPGSQL_STMT_PERFORM:
 			free_perform((PLpgSQL_stmt_perform *) stmt);
 			break;
+		case PLPGSQL_STMT_COMMIT:
+			free_commit((PLpgSQL_stmt_commit *) stmt);
+			break;
+		case PLPGSQL_STMT_ROLLBACK:
+			free_rollback((PLpgSQL_stmt_rollback *) stmt);
+			break;
 		default:
 			elog(ERROR, "unrecognized cmd_type: %d", stmt->cmd_type);
 			break;
@@ -590,6 +602,16 @@ free_perform(PLpgSQL_stmt_perform *stmt)
 	free_expr(stmt->expr);
 }
 
+static void
+free_commit(PLpgSQL_stmt_commit *stmt)
+{
+}
+
+static void
+free_rollback(PLpgSQL_stmt_rollback *stmt)
+{
+}
+
 static void
 free_exit(PLpgSQL_stmt_exit *stmt)
 {
@@ -777,6 +799,8 @@ static void dump_fetch(PLpgSQL_stmt_fetch *stmt);
 static void dump_cursor_direction(PLpgSQL_stmt_fetch *stmt);
 static void dump_close(PLpgSQL_stmt_close *stmt);
 static void dump_perform(PLpgSQL_stmt_perform *stmt);
+static void dump_commit(PLpgSQL_stmt_commit *stmt);
+static void dump_rollback(PLpgSQL_stmt_rollback *stmt);
 static void dump_expr(PLpgSQL_expr *expr);
 
 
@@ -867,6 +891,12 @@ dump_stmt(PLpgSQL_stmt *stmt)
 		case PLPGSQL_STMT_PERFORM:
 			dump_perform((PLpgSQL_stmt_perform *) stmt);
 			break;
+		case PLPGSQL_STMT_COMMIT:
+			dump_commit((PLpgSQL_stmt_commit *) stmt);
+			break;
+		case PLPGSQL_STMT_ROLLBACK:
+			dump_rollback((PLpgSQL_stmt_rollback *) stmt);
+			break;
 		default:
 			elog(ERROR, "unrecognized cmd_type: %d", stmt->cmd_type);
 			break;
@@ -1243,6 +1273,20 @@ dump_perform(PLpgSQL_stmt_perform *stmt)
 	printf("\n");
 }
 
+static void
+dump_commit(PLpgSQL_stmt_commit *stmt)
+{
+	dump_ind();
+	printf("COMMIT\n");
+}
+
+static void
+dump_rollback(PLpgSQL_stmt_rollback *stmt)
+{
+	dump_ind();
+	printf("ROLLBACK\n");
+}
+
 static void
 dump_exit(PLpgSQL_stmt_exit *stmt)
 {
diff --git a/src/pl/plpgsql/src/pl_gram.y b/src/pl/plpgsql/src/pl_gram.y
index 94f1f58593..e661750176 100644
--- a/src/pl/plpgsql/src/pl_gram.y
+++ b/src/pl/plpgsql/src/pl_gram.y
@@ -199,6 +199,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %type <stmt>	stmt_return stmt_raise stmt_assert stmt_execsql
 %type <stmt>	stmt_dynexecute stmt_for stmt_perform stmt_getdiag
 %type <stmt>	stmt_open stmt_fetch stmt_move stmt_close stmt_null
+%type <stmt>	stmt_commit stmt_rollback
 %type <stmt>	stmt_case stmt_foreach_a
 
 %type <list>	proc_exceptions
@@ -261,6 +262,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %token <keyword>	K_COLLATE
 %token <keyword>	K_COLUMN
 %token <keyword>	K_COLUMN_NAME
+%token <keyword>	K_COMMIT
 %token <keyword>	K_CONSTANT
 %token <keyword>	K_CONSTRAINT
 %token <keyword>	K_CONSTRAINT_NAME
@@ -326,6 +328,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %token <keyword>	K_RETURN
 %token <keyword>	K_RETURNED_SQLSTATE
 %token <keyword>	K_REVERSE
+%token <keyword>	K_ROLLBACK
 %token <keyword>	K_ROW_COUNT
 %token <keyword>	K_ROWTYPE
 %token <keyword>	K_SCHEMA
@@ -898,6 +901,10 @@ proc_stmt		: pl_block ';'
 						{ $$ = $1; }
 				| stmt_null
 						{ $$ = $1; }
+				| stmt_commit
+						{ $$ = $1; }
+				| stmt_rollback
+						{ $$ = $1; }
 				;
 
 stmt_perform	: K_PERFORM expr_until_semi
@@ -2174,6 +2181,31 @@ stmt_null		: K_NULL ';'
 					}
 				;
 
+stmt_commit		: K_COMMIT ';'
+					{
+						PLpgSQL_stmt_commit *new;
+
+						new = palloc(sizeof(PLpgSQL_stmt_commit));
+						new->cmd_type = PLPGSQL_STMT_COMMIT;
+						new->lineno = plpgsql_location_to_lineno(@1);
+
+						$$ = (PLpgSQL_stmt *)new;
+					}
+				;
+
+stmt_rollback	: K_ROLLBACK ';'
+					{
+						PLpgSQL_stmt_rollback *new;
+
+						new = palloc(sizeof(PLpgSQL_stmt_rollback));
+						new->cmd_type = PLPGSQL_STMT_ROLLBACK;
+						new->lineno = plpgsql_location_to_lineno(@1);
+
+						$$ = (PLpgSQL_stmt *)new;
+					}
+				;
+
+
 cursor_variable	: T_DATUM
 					{
 						/*
@@ -2410,6 +2442,7 @@ unreserved_keyword	:
 				| K_COLLATE
 				| K_COLUMN
 				| K_COLUMN_NAME
+				| K_COMMIT
 				| K_CONSTANT
 				| K_CONSTRAINT
 				| K_CONSTRAINT_NAME
@@ -2461,6 +2494,7 @@ unreserved_keyword	:
 				| K_RETURN
 				| K_RETURNED_SQLSTATE
 				| K_REVERSE
+				| K_ROLLBACK
 				| K_ROW_COUNT
 				| K_ROWTYPE
 				| K_SCHEMA
diff --git a/src/pl/plpgsql/src/pl_handler.c b/src/pl/plpgsql/src/pl_handler.c
index 1ebb7a7b5e..93a7ff2df3 100644
--- a/src/pl/plpgsql/src/pl_handler.c
+++ b/src/pl/plpgsql/src/pl_handler.c
@@ -18,6 +18,7 @@
 #include "access/htup_details.h"
 #include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
+#include "commands/defrem.h"
 #include "funcapi.h"
 #include "miscadmin.h"
 #include "utils/builtins.h"
@@ -255,7 +256,12 @@ plpgsql_call_handler(PG_FUNCTION_ARGS)
 			retval = (Datum) 0;
 		}
 		else
+		{
+			if (func->fn_rettype == InvalidOid &&
+				!castNode(CallContext, fcinfo->context)->atomic)
+				SPI_set_nonatomic();
 			retval = plpgsql_exec_function(func, fcinfo, NULL);
+		}
 	}
 	PG_CATCH();
 	{
@@ -304,6 +310,8 @@ plpgsql_inline_handler(PG_FUNCTION_ARGS)
 	if ((rc = SPI_connect()) != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed: %s", SPI_result_code_string(rc));
 
+	SPI_set_nonatomic();
+
 	/* Compile the anonymous code block */
 	func = plpgsql_compile_inline(codeblock->source_text);
 
diff --git a/src/pl/plpgsql/src/pl_scanner.c b/src/pl/plpgsql/src/pl_scanner.c
index 553be8c93c..a172031db2 100644
--- a/src/pl/plpgsql/src/pl_scanner.c
+++ b/src/pl/plpgsql/src/pl_scanner.c
@@ -106,6 +106,7 @@ static const ScanKeyword unreserved_keywords[] = {
 	PG_KEYWORD("collate", K_COLLATE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("column", K_COLUMN, UNRESERVED_KEYWORD)
 	PG_KEYWORD("column_name", K_COLUMN_NAME, UNRESERVED_KEYWORD)
+	PG_KEYWORD("commit", K_COMMIT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constant", K_CONSTANT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constraint", K_CONSTRAINT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constraint_name", K_CONSTRAINT_NAME, UNRESERVED_KEYWORD)
@@ -158,6 +159,7 @@ static const ScanKeyword unreserved_keywords[] = {
 	PG_KEYWORD("return", K_RETURN, UNRESERVED_KEYWORD)
 	PG_KEYWORD("returned_sqlstate", K_RETURNED_SQLSTATE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("reverse", K_REVERSE, UNRESERVED_KEYWORD)
+	PG_KEYWORD("rollback", K_ROLLBACK, UNRESERVED_KEYWORD)
 	PG_KEYWORD("row_count", K_ROW_COUNT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("rowtype", K_ROWTYPE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("schema", K_SCHEMA, UNRESERVED_KEYWORD)
diff --git a/src/pl/plpgsql/src/plpgsql.h b/src/pl/plpgsql/src/plpgsql.h
index 2b19948562..8494a4374d 100644
--- a/src/pl/plpgsql/src/plpgsql.h
+++ b/src/pl/plpgsql/src/plpgsql.h
@@ -105,7 +105,9 @@ typedef enum PLpgSQL_stmt_type
 	PLPGSQL_STMT_OPEN,
 	PLPGSQL_STMT_FETCH,
 	PLPGSQL_STMT_CLOSE,
-	PLPGSQL_STMT_PERFORM
+	PLPGSQL_STMT_PERFORM,
+	PLPGSQL_STMT_COMMIT,
+	PLPGSQL_STMT_ROLLBACK
 } PLpgSQL_stmt_type;
 
 /*
@@ -433,6 +435,24 @@ typedef struct PLpgSQL_stmt_perform
 	PLpgSQL_expr *expr;
 } PLpgSQL_stmt_perform;
 
+/*
+ * COMMIT statement
+ */
+typedef struct PLpgSQL_stmt_commit
+{
+	PLpgSQL_stmt_type cmd_type;
+	int			lineno;
+} PLpgSQL_stmt_commit;
+
+/*
+ * ROLLBACK statement
+ */
+typedef struct PLpgSQL_stmt_rollback
+{
+	PLpgSQL_stmt_type cmd_type;
+	int			lineno;
+} PLpgSQL_stmt_rollback;
+
 /*
  * GET DIAGNOSTICS item
  */
diff --git a/src/pl/plpython/Makefile b/src/pl/plpython/Makefile
index cc91afebde..d09910835d 100644
--- a/src/pl/plpython/Makefile
+++ b/src/pl/plpython/Makefile
@@ -90,6 +90,7 @@ REGRESS = \
 	plpython_quote \
 	plpython_composite \
 	plpython_subtransaction \
+	plpython_transaction \
 	plpython_drop
 
 REGRESS_PLPYTHON3_MANGLE := $(REGRESS)
diff --git a/src/pl/plpython/expected/plpython_test.out b/src/pl/plpython/expected/plpython_test.out
index 847e4cc412..f0a10cc05f 100644
--- a/src/pl/plpython/expected/plpython_test.out
+++ b/src/pl/plpython/expected/plpython_test.out
@@ -43,11 +43,12 @@ contents.sort()
 return contents
 $$ LANGUAGE plpythonu;
 select module_contents();
- module_contents 
------------------
+  module_contents  
+-------------------
  Error
  Fatal
  SPIError
+ commit
  cursor
  debug
  error
@@ -60,10 +61,12 @@ select module_contents();
  quote_ident
  quote_literal
  quote_nullable
+ rollback
  spiexceptions
+ start_transaction
  subtransaction
  warning
-(18 rows)
+(21 rows)
 
 CREATE FUNCTION elog_test_basic() RETURNS void
 AS $$
diff --git a/src/pl/plpython/expected/plpython_transaction.out b/src/pl/plpython/expected/plpython_transaction.out
new file mode 100644
index 0000000000..c664b5d1d2
--- /dev/null
+++ b/src/pl/plpython/expected/plpython_transaction.out
@@ -0,0 +1,83 @@
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+DO
+LANGUAGE plpythonu
+$$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+return 1
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/Python function "transaction_test2"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("CALL transaction_test1()")
+return 1
+$$;
+SELECT transaction_test3();
+ERROR:  spiexceptions.InvalidTransactionTermination: invalid transaction termination
+CONTEXT:  Traceback (most recent call last):
+  PL/Python function "transaction_test3", line 2, in <module>
+    plpy.execute("CALL transaction_test1()")
+PL/Python function "transaction_test3"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+DROP TABLE test1;
diff --git a/src/pl/plpython/plpy_main.c b/src/pl/plpython/plpy_main.c
index 7df50c09c8..ae83fcf5d1 100644
--- a/src/pl/plpython/plpy_main.c
+++ b/src/pl/plpython/plpy_main.c
@@ -9,6 +9,7 @@
 #include "access/htup_details.h"
 #include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
+#include "commands/defrem.h"
 #include "commands/trigger.h"
 #include "executor/spi.h"
 #include "miscadmin.h"
@@ -262,6 +263,9 @@ plpython_call_handler(PG_FUNCTION_ARGS)
 		else
 		{
 			proc = PLy_procedure_get(funcoid, InvalidOid, false);
+			if (proc->is_procedure &&
+				!castNode(CallContext, fcinfo->context)->atomic)
+					SPI_set_nonatomic();
 			exec_ctx->curr_proc = proc;
 			retval = PLy_exec_function(fcinfo, proc);
 		}
@@ -305,6 +309,7 @@ plpython_inline_handler(PG_FUNCTION_ARGS)
 	/* Note: SPI_finish() happens in plpy_exec.c, which is dubious design */
 	if (SPI_connect() != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed");
+	SPI_set_nonatomic();
 
 	MemSet(&fake_fcinfo, 0, sizeof(fake_fcinfo));
 	MemSet(&flinfo, 0, sizeof(flinfo));
@@ -424,7 +429,7 @@ PLy_push_execution_context(void)
 	PLyExecutionContext *context;
 
 	context = (PLyExecutionContext *)
-		MemoryContextAlloc(TopTransactionContext, sizeof(PLyExecutionContext));
+		MemoryContextAlloc(PortalContext, sizeof(PLyExecutionContext));
 	context->curr_proc = NULL;
 	context->scratch_ctx = NULL;
 	context->next = PLy_execution_contexts;
diff --git a/src/pl/plpython/plpy_plpymodule.c b/src/pl/plpython/plpy_plpymodule.c
index 759ad44932..a95e66bfee 100644
--- a/src/pl/plpython/plpy_plpymodule.c
+++ b/src/pl/plpython/plpy_plpymodule.c
@@ -6,8 +6,10 @@
 
 #include "postgres.h"
 
+#include "access/xact.h"
 #include "mb/pg_wchar.h"
 #include "utils/builtins.h"
+#include "utils/snapmgr.h"
 
 #include "plpython.h"
 
@@ -41,6 +43,9 @@ static PyObject *PLy_fatal(PyObject *self, PyObject *args, PyObject *kw);
 static PyObject *PLy_quote_literal(PyObject *self, PyObject *args);
 static PyObject *PLy_quote_nullable(PyObject *self, PyObject *args);
 static PyObject *PLy_quote_ident(PyObject *self, PyObject *args);
+static PyObject *PLy_start_transaction(PyObject *self, PyObject *args);
+static PyObject *PLy_commit(PyObject *self, PyObject *args);
+static PyObject *PLy_rollback(PyObject *self, PyObject *args);
 
 
 /* A list of all known exceptions, generated from backend/utils/errcodes.txt */
@@ -95,6 +100,13 @@ static PyMethodDef PLy_methods[] = {
 	 */
 	{"cursor", PLy_cursor, METH_VARARGS, NULL},
 
+	/*
+	 * transaction control
+	 */
+	{"start_transaction", PLy_start_transaction, METH_NOARGS, NULL},
+	{"commit", PLy_commit, METH_NOARGS, NULL},
+	{"rollback", PLy_rollback, METH_NOARGS, NULL},
+
 	{NULL, NULL, 0, NULL}
 };
 
@@ -577,3 +589,29 @@ PLy_output(volatile int level, PyObject *self, PyObject *args, PyObject *kw)
 	 */
 	Py_RETURN_NONE;
 }
+
+static PyObject *
+PLy_start_transaction(PyObject *self, PyObject *args)
+{
+	SPI_start_transaction();
+
+	Py_RETURN_NONE;
+}
+
+static PyObject *
+PLy_commit(PyObject *self, PyObject *args)
+{
+	SPI_commit();
+	SPI_start_transaction();
+
+	Py_RETURN_NONE;
+}
+
+static PyObject *
+PLy_rollback(PyObject *self, PyObject *args)
+{
+	SPI_rollback();
+	SPI_start_transaction();
+
+	Py_RETURN_NONE;
+}
diff --git a/src/pl/plpython/sql/plpython_transaction.sql b/src/pl/plpython/sql/plpython_transaction.sql
new file mode 100644
index 0000000000..ac98a81e1b
--- /dev/null
+++ b/src/pl/plpython/sql/plpython_transaction.sql
@@ -0,0 +1,69 @@
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+DO
+LANGUAGE plpythonu
+$$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+return 1
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("CALL transaction_test1()")
+return 1
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+DROP TABLE test1;
diff --git a/src/pl/tcl/Makefile b/src/pl/tcl/Makefile
index 6a92a9b6aa..ef61ee596e 100644
--- a/src/pl/tcl/Makefile
+++ b/src/pl/tcl/Makefile
@@ -28,7 +28,7 @@ DATA = pltcl.control pltcl--1.0.sql pltcl--unpackaged--1.0.sql \
        pltclu.control pltclu--1.0.sql pltclu--unpackaged--1.0.sql
 
 REGRESS_OPTS = --dbname=$(PL_TESTDB) --load-extension=pltcl
-REGRESS = pltcl_setup pltcl_queries pltcl_call pltcl_start_proc pltcl_subxact pltcl_unicode
+REGRESS = pltcl_setup pltcl_queries pltcl_call pltcl_start_proc pltcl_subxact pltcl_unicode pltcl_transaction
 
 # Tcl on win32 ships with import libraries only for Microsoft Visual C++,
 # which are not compatible with mingw gcc. Therefore we need to build a
diff --git a/src/pl/tcl/expected/pltcl_transaction.out b/src/pl/tcl/expected/pltcl_transaction.out
new file mode 100644
index 0000000000..6ce900027c
--- /dev/null
+++ b/src/pl/tcl/expected/pltcl_transaction.out
@@ -0,0 +1,63 @@
+-- suppress CONTEXT so that function OIDs aren't in output
+\set VERBOSITY terse
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+return 1
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE pltcl
+AS $$
+spi_exec "CALL transaction_test1()"
+return 1
+$$;
+SELECT transaction_test3();
+ERROR:  invalid transaction termination
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+DROP TABLE test1;
diff --git a/src/pl/tcl/pltcl.c b/src/pl/tcl/pltcl.c
index e0792d93e1..816882e92c 100644
--- a/src/pl/tcl/pltcl.c
+++ b/src/pl/tcl/pltcl.c
@@ -18,6 +18,7 @@
 #include "catalog/objectaccess.h"
 #include "catalog/pg_proc.h"
 #include "catalog/pg_type.h"
+#include "commands/defrem.h"
 #include "commands/event_trigger.h"
 #include "commands/trigger.h"
 #include "executor/spi.h"
@@ -312,6 +313,10 @@ static int pltcl_SPI_lastoid(ClientData cdata, Tcl_Interp *interp,
 				  int objc, Tcl_Obj *const objv[]);
 static int pltcl_subtransaction(ClientData cdata, Tcl_Interp *interp,
 					 int objc, Tcl_Obj *const objv[]);
+static int pltcl_commit(ClientData cdata, Tcl_Interp *interp,
+					 int objc, Tcl_Obj *const objv[]);
+static int pltcl_rollback(ClientData cdata, Tcl_Interp *interp,
+					 int objc, Tcl_Obj *const objv[]);
 
 static void pltcl_subtrans_begin(MemoryContext oldcontext,
 					 ResourceOwner oldowner);
@@ -524,6 +529,10 @@ pltcl_init_interp(pltcl_interp_desc *interp_desc, Oid prolang, bool pltrusted)
 						 pltcl_SPI_lastoid, NULL, NULL);
 	Tcl_CreateObjCommand(interp, "subtransaction",
 						 pltcl_subtransaction, NULL, NULL);
+	Tcl_CreateObjCommand(interp, "commit",
+						 pltcl_commit, NULL, NULL);
+	Tcl_CreateObjCommand(interp, "rollback",
+						 pltcl_rollback, NULL, NULL);
 
 	/************************************************************
 	 * Call the appropriate start_proc, if there is one.
@@ -812,6 +821,10 @@ pltcl_func_handler(PG_FUNCTION_ARGS, pltcl_call_state *call_state,
 	prodesc = compile_pltcl_function(fcinfo->flinfo->fn_oid, InvalidOid,
 									 false, pltrusted);
 
+	if (prodesc->result_typid == InvalidOid &&
+		!castNode(CallContext, fcinfo->context)->atomic)
+		SPI_set_nonatomic();
+
 	call_state->prodesc = prodesc;
 	prodesc->fn_refcount++;
 
@@ -2935,6 +2948,38 @@ pltcl_subtransaction(ClientData cdata, Tcl_Interp *interp,
 }
 
 
+/**********************************************************************
+ * pltcl_commit()
+ *
+ * Commit the transaction and start a new one.
+ **********************************************************************/
+static int
+pltcl_commit(ClientData cdata, Tcl_Interp *interp,
+			 int objc, Tcl_Obj *const objv[])
+{
+	SPI_commit();
+	SPI_start_transaction();
+
+	return TCL_OK;
+}
+
+
+/**********************************************************************
+ * pltcl_rollback()
+ *
+ * Abort the transaction and start a new one.
+ **********************************************************************/
+static int
+pltcl_rollback(ClientData cdata, Tcl_Interp *interp,
+			   int objc, Tcl_Obj *const objv[])
+{
+	SPI_rollback();
+	SPI_start_transaction();
+
+	return TCL_OK;
+}
+
+
 /**********************************************************************
  * pltcl_set_tuple_values() - Set variables for all attributes
  *				  of a given tuple
diff --git a/src/pl/tcl/sql/pltcl_transaction.sql b/src/pl/tcl/sql/pltcl_transaction.sql
new file mode 100644
index 0000000000..14aed5844a
--- /dev/null
+++ b/src/pl/tcl/sql/pltcl_transaction.sql
@@ -0,0 +1,60 @@
+-- suppress CONTEXT so that function OIDs aren't in output
+\set VERBOSITY terse
+
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+return 1
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE pltcl
+AS $$
+spi_exec "CALL transaction_test1()"
+return 1
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+DROP TABLE test1;
diff --git a/src/test/regress/expected/plpgsql.out b/src/test/regress/expected/plpgsql.out
index d6e5bc3353..040f667f8e 100644
--- a/src/test/regress/expected/plpgsql.out
+++ b/src/test/regress/expected/plpgsql.out
@@ -6077,7 +6077,103 @@ SELECT * FROM proc_test1;
  55
 (1 row)
 
+TRUNCATE proc_test1;
+CREATE PROCEDURE test_proc_transaction1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+CALL test_proc_transaction1();
+SELECT * FROM proc_test1;
+ a 
+---
+ 0
+ 2
+ 4
+ 6
+ 8
+(5 rows)
+
+TRUNCATE proc_test1;
+DO
+LANGUAGE plpgsql
+$$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+SELECT * FROM proc_test1;
+ a 
+---
+ 0
+ 2
+ 4
+ 6
+ 8
+(5 rows)
+
+TRUNCATE proc_test1;
+-- not allowed in a function
+CREATE FUNCTION test_proc_transaction2() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+    RETURN 1;
+END
+$$;
+SELECT test_proc_transaction2();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function test_proc_transaction2() line 6 at COMMIT
+SELECT * FROM proc_test1;
+ a 
+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION test_proc_transaction3() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    CALL test_proc_transaction1();
+    RETURN 1;
+END;
+$$;
+SELECT test_proc_transaction3();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function test_proc_transaction1() line 6 at COMMIT
+SQL statement "CALL test_proc_transaction1()"
+PL/pgSQL function test_proc_transaction3() line 3 at SQL statement
+SELECT * FROM proc_test1;
+ a 
+---
+(0 rows)
+
 DROP PROCEDURE test_proc1;
 DROP PROCEDURE test_proc2;
 DROP PROCEDURE test_proc3;
+DROP PROCEDURE test_proc_transaction1;
 DROP TABLE proc_test1;
diff --git a/src/test/regress/sql/plpgsql.sql b/src/test/regress/sql/plpgsql.sql
index 1c355132b7..a0e4821e0c 100644
--- a/src/test/regress/sql/plpgsql.sql
+++ b/src/test/regress/sql/plpgsql.sql
@@ -4864,8 +4864,90 @@ CREATE PROCEDURE test_proc3(x int)
 SELECT * FROM proc_test1;
 
 
+TRUNCATE proc_test1;
+
+CREATE PROCEDURE test_proc_transaction1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+CALL test_proc_transaction1();
+
+SELECT * FROM proc_test1;
+
+
+TRUNCATE proc_test1;
+
+DO
+LANGUAGE plpgsql
+$$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+SELECT * FROM proc_test1;
+
+
+TRUNCATE proc_test1;
+
+-- not allowed in a function
+CREATE FUNCTION test_proc_transaction2() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+    RETURN 1;
+END
+$$;
+
+SELECT test_proc_transaction2();
+
+SELECT * FROM proc_test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION test_proc_transaction3() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    CALL test_proc_transaction1();
+    RETURN 1;
+END;
+$$;
+
+SELECT test_proc_transaction3();
+
+SELECT * FROM proc_test1;
+
+
 DROP PROCEDURE test_proc1;
 DROP PROCEDURE test_proc2;
 DROP PROCEDURE test_proc3;
+DROP PROCEDURE test_proc_transaction1;
 
 DROP TABLE proc_test1;
-- 
2.15.0

#9Merlin Moncure
mmoncure@gmail.com
In reply to: Peter Eisentraut (#7)
Re: [HACKERS] Transaction control in procedures

On Tue, Nov 14, 2017 at 5:27 PM, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

On 11/14/17 16:33, Merlin Moncure wrote:

One detail in your example is that when you enter the procedure, you are
already in a transaction, so you would have to run either COMMIT or
ROLLBACK before the START TRANSACTION.

Ok, that's good, but it seems a little wonky to me to have to issue
COMMIT first. Shouldn't that be the default? Meaning you would not
be *in* a transaction unless you specified to be in one.

But that's not how this feature is defined in the SQL standard and AFAIK
other implementations. When you enter the procedure call, you are in a
transaction. For one thing, a procedure does not *have* to do
transaction control. So if it's a plain old procedure like a function
that just runs a few statements, there needs to be a transaction.

Hm, OK. Well, SQL Server (which is pretty far from the SQL standard)
works that way. See here:
http://www.4guysfromrolla.com/webtech/080305-1.shtml. DB2, which is
very close to the SQL standard, only supports COMMIT/ROLLBACK (not
begin/start etc)
https://www.ibm.com/support/knowledgecenter/en/SSULQD_7.2.0/com.ibm.nz.sproc.doc/c_sproc_transaction_commits_and_rollbacks.html.
Either approach is ok I guess, and always being in a transaction
probably has some advantages. performance being an obvious one. With
DB2, the COMMIT statement acts as kind of a flush, or a paired
'commit;begin;'.

Can we zero in on this? The question implied, 'can you do this
without being in a transaction'? PERFORM do_stuff() is a implicit
transaction, so it ought to end when the function returns right?
Meaning, assuming I was not already in a transaction when hitting this
block, I would not be subject to an endless transaction duration?

In the server, you are always in a transaction, so that's not how this
works. I think this also ties into my first response above.

I'll try this out myself, but as long as we can have a *bounded*
transaction lifetime (basically the time to do stuff + 1 second) via
something like:
LOOP
<do stuff>
COMMIT;
PERFORM pg_sleep(1);
END LOOP;

... I'm good. I'll try your patch out ASAP. Thanks for answering all
my questions.

merlin

#10Pavel Stehule
pavel.stehule@gmail.com
In reply to: Merlin Moncure (#9)
Re: [HACKERS] Transaction control in procedures

2017-11-15 14:38 GMT+01:00 Merlin Moncure <mmoncure@gmail.com>:

On Tue, Nov 14, 2017 at 5:27 PM, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

On 11/14/17 16:33, Merlin Moncure wrote:

One detail in your example is that when you enter the procedure, you

are

already in a transaction, so you would have to run either COMMIT or
ROLLBACK before the START TRANSACTION.

Ok, that's good, but it seems a little wonky to me to have to issue
COMMIT first. Shouldn't that be the default? Meaning you would not
be *in* a transaction unless you specified to be in one.

But that's not how this feature is defined in the SQL standard and AFAIK
other implementations. When you enter the procedure call, you are in a
transaction. For one thing, a procedure does not *have* to do
transaction control. So if it's a plain old procedure like a function
that just runs a few statements, there needs to be a transaction.

Hm, OK. Well, SQL Server (which is pretty far from the SQL standard)
works that way. See here:
http://www.4guysfromrolla.com/webtech/080305-1.shtml. DB2, which is
very close to the SQL standard, only supports COMMIT/ROLLBACK (not
begin/start etc)
https://www.ibm.com/support/knowledgecenter/en/SSULQD_7.2.
0/com.ibm.nz.sproc.doc/c_sproc_transaction_commits_and_rollbacks.html.
Either approach is ok I guess, and always being in a transaction
probably has some advantages. performance being an obvious one. With
DB2, the COMMIT statement acts as kind of a flush, or a paired
'commit;begin;'.

same in Oracle PL/SQL

Show quoted text

Can we zero in on this? The question implied, 'can you do this
without being in a transaction'? PERFORM do_stuff() is a implicit
transaction, so it ought to end when the function returns right?
Meaning, assuming I was not already in a transaction when hitting this
block, I would not be subject to an endless transaction duration?

In the server, you are always in a transaction, so that's not how this
works. I think this also ties into my first response above.

I'll try this out myself, but as long as we can have a *bounded*
transaction lifetime (basically the time to do stuff + 1 second) via
something like:
LOOP
<do stuff>
COMMIT;
PERFORM pg_sleep(1);
END LOOP;

... I'm good. I'll try your patch out ASAP. Thanks for answering all
my questions.

merlin

#11Merlin Moncure
mmoncure@gmail.com
In reply to: Merlin Moncure (#9)
Re: [HACKERS] Transaction control in procedures

On Wed, Nov 15, 2017 at 7:38 AM, Merlin Moncure <mmoncure@gmail.com> wrote:

On Tue, Nov 14, 2017 at 5:27 PM, Peter Eisentraut

Can we zero in on this? The question implied, 'can you do this
without being in a transaction'? PERFORM do_stuff() is a implicit
transaction, so it ought to end when the function returns right?
Meaning, assuming I was not already in a transaction when hitting this
block, I would not be subject to an endless transaction duration?

In the server, you are always in a transaction, so that's not how this
works. I think this also ties into my first response above.

I'll try this out myself, but as long as we can have a *bounded*
transaction lifetime (basically the time to do stuff + 1 second) via
something like:
LOOP
<do stuff>
COMMIT;
PERFORM pg_sleep(1);
END LOOP;

... I'm good. I'll try your patch out ASAP. Thanks for answering all
my questions.

Trying this out (v2 both patches, compiled clean, thank you!),
postgres=# CREATE OR REPLACE PROCEDURE foo() AS
$$
BEGIN
LOOP
PERFORM 1;
COMMIT;
RAISE NOTICE '%', now();
PERFORM pg_sleep(1);
END LOOP;
END;
$$ LANGUAGE PLPGSQL;
CREATE PROCEDURE
Time: 0.996 ms
postgres=# call foo();
NOTICE: 2017-11-15 08:52:08.936025-06
NOTICE: 2017-11-15 08:52:08.936025-06

... I noticed that:
*) now() did not advance with commit and,
*) xact_start via pg_stat_activity did not advance

Shouldn't both of those advance with the in-loop COMMIT?

merlin

#12Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: legrand legrand (#6)
Re: Transaction control in procedures

On 11/14/17 17:40, legrand legrand wrote:

will that kind of statement (that is permitted with Oracle but gives errors
ora-1555 snapshot too old) be permitted ?

begin
for c in (select id from tab where cond='blabla')
loop
update tab set x=1 where id=c.id;
commit;
end loop;
end;

Hmm, that currently results in

ERROR: cannot commit while a portal is pinned

You say this fails in Oracle too. Are we supposed to make this work
somehow?

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#13Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: Simon Riggs (#2)
Re: [HACKERS] Transaction control in procedures

On 11/8/17 18:48, Simon Riggs wrote:

What would happen if some of the INSERTs failed? Where would control
go to? (Maybe this is just "no change" in this particular proc)

An exception is raised and unless the exception is caught (depending on
the PL), control leaves the procedure. What is already committed stays.

What happens if the procedure is updated during execution? Presumably
it keeps executing the original version as seen in the initial
snapshot?

correct

Does the xmin of this session advance after each transaction, or do we
hold the snapshot used for the procedure body open, causing us to hold
back xmin and prevent vacuuming from being effective?

What would happen if a procedure recursively called itself? And yet it
was updated half-way through? Would that throw an error (I think it
should).

I don't think anything special happens here. The snapshot that is used
to read the procedure source code and other meta information is released
at a transaction boundary.

3) The PL implementations themselves allocate memory in
transaction-bound contexts for convenience as well. This is usually
easy to fix by switching to PortalContext as well. As you see, the
PL/Python code part of the patch is actually very small. Changes in
other PLs would be similar.

Is there some kind of interlock to prevent dropping the portal half way thru?

I should probably look this up, but I don't think this is fundamentally
different from how VACUUM and CREATE INDEX CONCURRENTLY run inside a
portal and issue multiple transactions in sequence.

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#14Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: Merlin Moncure (#11)
Re: [HACKERS] Transaction control in procedures

On 11/15/17 09:54, Merlin Moncure wrote:

... I noticed that:
*) now() did not advance with commit and,
*) xact_start via pg_stat_activity did not advance

Shouldn't both of those advance with the in-loop COMMIT?

I think you are correct. I'll include that in the next patch version.
It shouldn't be difficult.

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#15legrand legrand
legrand_legrand@hotmail.com
In reply to: Peter Eisentraut (#12)
RE: Transaction control in procedures

We are just opening the "close cursors on/at commit" specification ;o)

- MS SQL server: cursor_close_on_commit
- Firebird: close_cursors_at_commit
- DB2: "with hold" syntax
- ...

I think it a plus to support keeping opened cursors at commit time,
but impacts have to be checked in details ...

Oracle Ora-1555 error comes in the extreme situation where rows used inside the cursor are modified, commited, before to be fetched.

#16Merlin Moncure
mmoncure@gmail.com
In reply to: Peter Eisentraut (#14)
Re: [HACKERS] Transaction control in procedures

On Wed, Nov 15, 2017 at 3:42 PM, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

On 11/15/17 09:54, Merlin Moncure wrote:

... I noticed that:
*) now() did not advance with commit and,
*) xact_start via pg_stat_activity did not advance

Shouldn't both of those advance with the in-loop COMMIT?

I think you are correct. I'll include that in the next patch version.
It shouldn't be difficult.

Thanks. A couple of more things.

*) This error message is incorrect now:
postgres=# CREATE OR REPLACE PROCEDURE foo() AS
$$
BEGIN
LOOP
SAVEPOINT x;
END LOOP;
END;
$$ LANGUAGE PLPGSQL;
CREATE PROCEDURE
Time: 0.912 ms
postgres=# call foo();
ERROR: cannot begin/end transactions in PL/pgSQL
HINT: Use a BEGIN block with an EXCEPTION clause instead.
CONTEXT: PL/pgSQL function foo() line 5 at SQL statement

I guess there are a few places that assume pl/pgsql is always run from
a in-transaction function.

*) Exception handlers seem to override COMMITs. The the following
procedure will not insert any rows. I wonder if this is the correct
behavior. I think there's a pretty good case to be made to raise an
error if a COMMIT is issued if you're in an exception block.

CREATE OR REPLACE PROCEDURE foo() AS
$$
BEGIN
LOOP
INSERT INTO foo DEFAULT VALUES;
COMMIT;
RAISE EXCEPTION 'test';
END LOOP;
EXCEPTION
WHEN OTHERS THEN RAISE NOTICE '%', SQLERRM;
END;
$$ LANGUAGE PLPGSQL;

*) The documentation could use some work. Would you like some help?

merlin

#17Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: legrand legrand (#15)
Re: Transaction control in procedures

On 11/16/17 07:04, legrand legrand wrote:

We are just opening the� "close cursors on/at commit" specification ;o)

- MS SQL server: cursor_close_on_commit
- Firebird: close_cursors_at_commit
- DB2: "with hold" syntax
- ...

I think it a plus to support�keeping opened cursors at commit time,
but impacts have to be checked in details ...

I think the facilities to support this in PostgreSQL are already there.
We'd just have to tweak PL/pgSQL to make some of its internal portals
"held" and then clean them up manually at some later point. So I think
this is a localized detail, not a fundamental problem.

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#18Merlin Moncure
mmoncure@gmail.com
In reply to: Peter Eisentraut (#17)
Re: Transaction control in procedures

On Thu, Nov 16, 2017 at 12:36 PM, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

On 11/16/17 07:04, legrand legrand wrote:

We are just opening the "close cursors on/at commit" specification ;o)

- MS SQL server: cursor_close_on_commit
- Firebird: close_cursors_at_commit
- DB2: "with hold" syntax
- ...

I think it a plus to support keeping opened cursors at commit time,
but impacts have to be checked in details ...

I think the facilities to support this in PostgreSQL are already there.
We'd just have to tweak PL/pgSQL to make some of its internal portals
"held" and then clean them up manually at some later point. So I think
this is a localized detail, not a fundamental problem.

Automatically persisting cursors (WITH HOLD) can have some very
surprising performance considerations, except when the current code
execution depends on that particular cursor, in which case the current
behavior of raising a (hopefully better worded-) error seems
appropriate. Cursors based on temporary tables could be exempt from
having to be closed or checked on COMMIT.

plpgsql does not have the facility to create held cursors
FWICT...automatic promotion seems pretty dubious. It could certainly
be added, and cursors so held could be exempt from being force
closed/errored as well. In lieu of that, having users materialize data
in to temp tables for such cases seems reasonable.

merlin

#19Simon Riggs
simon@2ndquadrant.com
In reply to: Peter Eisentraut (#13)
Re: [HACKERS] Transaction control in procedures

On 15 November 2017 at 16:36, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

On 11/8/17 18:48, Simon Riggs wrote:

What would happen if some of the INSERTs failed? Where would control
go to? (Maybe this is just "no change" in this particular proc)

An exception is raised and unless the exception is caught (depending on
the PL), control leaves the procedure. What is already committed stays.

What happens if the procedure is updated during execution? Presumably
it keeps executing the original version as seen in the initial
snapshot?

correct

Does the xmin of this session advance after each transaction, or do we
hold the snapshot used for the procedure body open, causing us to hold
back xmin and prevent vacuuming from being effective?

What would happen if a procedure recursively called itself? And yet it
was updated half-way through? Would that throw an error (I think it
should).

I don't think anything special happens here. The snapshot that is used
to read the procedure source code and other meta information is released
at a transaction boundary.

I think we need to document that, or at least note in README

It's quite important for VACUUM.

--
Simon Riggs http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#20Simon Riggs
simon@2ndquadrant.com
In reply to: Peter Eisentraut (#4)
Re: [HACKERS] Transaction control in procedures

On 14 November 2017 at 13:09, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

*) Will pg_cancel_backend() cancel the currently executing statement
or the procedure? (I guess probably the procedure but I'm curious)

Same as the way it currently works. It will raise an exception, which
will travel up the stack and eventually issue an error or be caught. If
someone knows more specific concerns here I could look into it, but I
don't see any problem.

*) Will long running procedures be subject to statement timeout (and
does it apply to the entire procedure)?

See previous item.

Will they be able to control
statement_timeout from within the procedure itself?

The statement timeout alarm is set by the top-level execution loop, so
you can't change a statement timeout that is already in progress. But
you could change the GUC and commit it for the next top-level statement.

*) Will pg_stat_activity show the invoking CALL or the currently
executing statement? I see a strong argument for showing both of
these things. although I understand that's out of scope here.

Not different from a function execution, i.e., top-level statement.

Which is the "top-level statement"? The CALL or the currently
executing statement within the proc? I think you mean former.

For the first two answers above the answer was "currently executing
statement", yet the third answer seems to be the procedure. So that is
a slight discrepancy.

ISTM we would like

1) a way to cancel execution of a procedure
2) a way to set a timeout to cancel execution of a procedure

as well as

1) a way to cancel execution of a statement that is running within a procedure
2) a way to set a timeout to cancel execution of a statement in a procedure

Visibility of what a routine is currently executing is the role of a
debugger utility/API.

--
Simon Riggs http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#21Merlin Moncure
mmoncure@gmail.com
In reply to: Simon Riggs (#20)
Re: [HACKERS] Transaction control in procedures

On Thu, Nov 16, 2017 at 5:35 PM, Simon Riggs <simon@2ndquadrant.com> wrote:

On 14 November 2017 at 13:09, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

*) Will pg_cancel_backend() cancel the currently executing statement
or the procedure? (I guess probably the procedure but I'm curious)

Same as the way it currently works. It will raise an exception, which
will travel up the stack and eventually issue an error or be caught. If
someone knows more specific concerns here I could look into it, but I
don't see any problem.

*) Will long running procedures be subject to statement timeout (and
does it apply to the entire procedure)?

See previous item.

Will they be able to control
statement_timeout from within the procedure itself?

The statement timeout alarm is set by the top-level execution loop, so
you can't change a statement timeout that is already in progress. But
you could change the GUC and commit it for the next top-level statement.

*) Will pg_stat_activity show the invoking CALL or the currently
executing statement? I see a strong argument for showing both of
these things. although I understand that's out of scope here.

Not different from a function execution, i.e., top-level statement.

Which is the "top-level statement"? The CALL or the currently
executing statement within the proc? I think you mean former.

For the first two answers above the answer was "currently executing
statement", yet the third answer seems to be the procedure. So that is
a slight discrepancy.

ISTM we would like

1) a way to cancel execution of a procedure
2) a way to set a timeout to cancel execution of a procedure

as well as

1) a way to cancel execution of a statement that is running within a procedure
2) a way to set a timeout to cancel execution of a statement in a procedure

Visibility of what a routine is currently executing is the role of a
debugger utility/API.

How could you cancel a statement but not the procedure itself?
Cancelling (either by timeout or administrative) type errors
untrappable by design for very good reasons and untrapped errors ought
to return the database all the way to 'ready for query'.

merlin

#22Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: Simon Riggs (#20)
Re: [HACKERS] Transaction control in procedures

On 11/16/17 18:35, Simon Riggs wrote:

For the first two answers above the answer was "currently executing
statement", yet the third answer seems to be the procedure. So that is
a slight discrepancy.

That's the way function execution, or really any nested execution,
currently works.

ISTM we would like

1) a way to cancel execution of a procedure
2) a way to set a timeout to cancel execution of a procedure

as well as

1) a way to cancel execution of a statement that is running within a procedure
2) a way to set a timeout to cancel execution of a statement in a procedure

Visibility of what a routine is currently executing is the role of a
debugger utility/API.

That would probably be nice, but it would be an entirely separate
undertaking. In particular, getting insight into some kind of execution
stack would necessarily be language specific. We do have some of that
for PL/pgSQL of course.

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#23Simon Riggs
simon@2ndquadrant.com
In reply to: Peter Eisentraut (#22)
Re: [HACKERS] Transaction control in procedures

On 18 November 2017 at 02:16, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

On 11/16/17 18:35, Simon Riggs wrote:

For the first two answers above the answer was "currently executing
statement", yet the third answer seems to be the procedure. So that is
a slight discrepancy.

That's the way function execution, or really any nested execution,
currently works.

I'm impressed that these features are so clean and simple. I wasn't
expecting that. I have very few review comments.

I vote in favour of applying these patches at the end of this CF, end of 11/17.
* Procedures
* Transaction control in PL/pgSQL (only)

That will give us 3 months to discuss problems and find solutions,
then later we can commit PL/Python, PL/perl and PL/tcl once we know
where the dragons are hiding.

If we delay, we will end up with some weird gotcha that needs changing
in the next release.

--
Simon Riggs http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#24Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: Peter Eisentraut (#1)
Re: [HACKERS] Transaction control in procedures

On 10/31/17 15:38, Peter Eisentraut wrote:

2) SPI needs some work. It thinks that it can clean everything away at
transaction end. I have found that instead of TopTransactionContext one
can use PortalContext and get a more suitable life cycle for the memory.
I have played with some variants to make this configurable (e.g.,
argument to SPI_connect()), but that didn't seem very useful. There are
some comments indicating that there might not always be a PortalContext,
but the existing tests don't seem to mind. (There was a thread recently
about making a fake PortalContext for autovacuum, so maybe the current
idea is that we make sure there always is a PortalContext.) Maybe we
need another context like StatementContext or ProcedureContext.

This could use more specific discussion, as it is a critical point.

One general theme in this patch is to use PortalContext instead of
TopTransactionContext (or similar). In SPI_connect(), we have

/*
* Create memory contexts for this procedure
*
* XXX it would be better to use PortalContext as the parent
context, but
* we may not be inside a portal (consider deferred-trigger execution).
* Perhaps CurTransactionContext would do? For now it doesn't matter
* because we clean up explicitly in AtEOSubXact_SPI().
*/
_SPI_current->procCxt = AllocSetContextCreate(TopTransactionContext,
"SPI Proc",

and my patch changes that to PortalContext in defiance of that comment.

So either the comment is incorrect or we have insufficient test coverage
or something in between.

ISTM that in the normal case, at the time deferred triggers are
executed, we are in the portal that executes the COMMIT command, so that
should work. There are some cases that call CommitTransactionCommand()
internally, but they don't run in cases when triggers are pending (e.g.,
VACUUM). Although logical apply workers might be a problem, but they
clearly postdate that comment.

In any case, the precedent in autovacuum appears to be to make a fake
PortalContext if needed, so we could do that. Can we think of other
cases where that might be necessary, so I can construct some test cases?

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#25Michael Paquier
michael.paquier@gmail.com
In reply to: Peter Eisentraut (#24)
Re: [HACKERS] Transaction control in procedures

On Wed, Nov 29, 2017 at 3:33 AM, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

[snip]

Moved to next CF as the discussion is still hot.
--
Michael

#26Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: Peter Eisentraut (#8)
1 attachment(s)
Re: [HACKERS] Transaction control in procedures

On 11/14/17 18:38, Peter Eisentraut wrote:

On 10/31/17 15:38, Peter Eisentraut wrote:

Here is a patch that implements transaction control in PL/Python
procedures. (This patch goes on top of "SQL procedures" patch v1.)

Here is an updated patch, now on top of "SQL procedures" v2.

Here is a new patch, now on top of master. The main changes are that a
lot of documentation has been added.

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

Attachments:

v3-0001-Transaction-control-in-PL-procedures.patchtext/plain; charset=UTF-8; name=v3-0001-Transaction-control-in-PL-procedures.patch; x-mac-creator=0; x-mac-type=0Download
From 1a5e5fde2c0da663cc010b3e19418d0b2141304b Mon Sep 17 00:00:00 2001
From: Peter Eisentraut <peter_e@gmx.net>
Date: Fri, 1 Dec 2017 14:40:29 -0500
Subject: [PATCH v3] Transaction control in PL procedures

In each of the supplied procedural languages (PL/pgSQL, PL/Perl,
PL/Python, PL/Tcl), add language-specific commit and rollback
functions/commands to control transactions in procedures in that
language.  Add similar underlying functions to SPI.  Some additional
cleanup so that transaction commit or abort doesn't blow away data
structures still used by the procedure call.  Add execution context
tracking to CALL and DO statements so that transaction control commands
can only be issued in top-level procedure and block calls, not function
calls or other procedure or block calls.
---
 doc/src/sgml/plperl.sgml                          |  49 +++++
 doc/src/sgml/plpgsql.sgml                         |  86 +++++----
 doc/src/sgml/plpython.sgml                        |  34 ++++
 doc/src/sgml/pltcl.sgml                           |  37 ++++
 doc/src/sgml/spi.sgml                             | 219 ++++++++++++++++++++++
 src/backend/commands/functioncmds.c               |  30 ++-
 src/backend/executor/spi.c                        |  92 +++++++--
 src/backend/tcop/utility.c                        |   4 +-
 src/backend/utils/mmgr/portalmem.c                |  39 ++--
 src/include/commands/defrem.h                     |   4 +-
 src/include/executor/spi.h                        |   5 +
 src/include/executor/spi_priv.h                   |   4 +
 src/include/nodes/nodes.h                         |   3 +-
 src/include/nodes/parsenodes.h                    |   7 +
 src/pl/plperl/GNUmakefile                         |   2 +-
 src/pl/plperl/SPI.xs                              |  12 ++
 src/pl/plperl/expected/plperl_transaction.out     |  94 ++++++++++
 src/pl/plperl/plperl.c                            |   6 +
 src/pl/plperl/sql/plperl_transaction.sql          |  88 +++++++++
 src/pl/plpgsql/src/pl_exec.c                      |  48 ++++-
 src/pl/plpgsql/src/pl_funcs.c                     |  44 +++++
 src/pl/plpgsql/src/pl_gram.y                      |  34 ++++
 src/pl/plpgsql/src/pl_handler.c                   |   8 +
 src/pl/plpgsql/src/pl_scanner.c                   |   2 +
 src/pl/plpgsql/src/plpgsql.h                      |  22 ++-
 src/pl/plpython/Makefile                          |   1 +
 src/pl/plpython/expected/plpython_test.out        |   4 +-
 src/pl/plpython/expected/plpython_transaction.out |  96 ++++++++++
 src/pl/plpython/plpy_main.c                       |   7 +-
 src/pl/plpython/plpy_plpymodule.c                 |  28 +++
 src/pl/plpython/sql/plpython_transaction.sql      |  80 ++++++++
 src/pl/tcl/Makefile                               |   2 +-
 src/pl/tcl/expected/pltcl_transaction.out         |  63 +++++++
 src/pl/tcl/pltcl.c                                |  44 +++++
 src/pl/tcl/sql/pltcl_transaction.sql              |  60 ++++++
 src/test/regress/expected/plpgsql.out             | 110 +++++++++++
 src/test/regress/sql/plpgsql.sql                  |  95 ++++++++++
 37 files changed, 1461 insertions(+), 102 deletions(-)
 create mode 100644 src/pl/plperl/expected/plperl_transaction.out
 create mode 100644 src/pl/plperl/sql/plperl_transaction.sql
 create mode 100644 src/pl/plpython/expected/plpython_transaction.out
 create mode 100644 src/pl/plpython/sql/plpython_transaction.sql
 create mode 100644 src/pl/tcl/expected/pltcl_transaction.out
 create mode 100644 src/pl/tcl/sql/pltcl_transaction.sql

diff --git a/doc/src/sgml/plperl.sgml b/doc/src/sgml/plperl.sgml
index 100162dead..82ddf26606 100644
--- a/doc/src/sgml/plperl.sgml
+++ b/doc/src/sgml/plperl.sgml
@@ -661,6 +661,55 @@ <title>Database Access from PL/Perl</title>
     </para>
     </listitem>
     </varlistentry>
+
+    <varlistentry>
+     <term>
+      <literal><function>spi_commit()</function></literal>
+      <indexterm>
+       <primary>spi_commit</primary>
+       <secondary>in PL/Perl</secondary>
+     </indexterm>
+     </term>
+     <term>
+      <literal><function>spi_rollback()</function></literal>
+      <indexterm>
+       <primary>spi_rollback</primary>
+       <secondary>in PL/Perl</secondary>
+      </indexterm>
+     </term>
+     <listitem>
+      <para>
+       Commit or roll back the current transaction.  This can only be called
+       in a procedure or anonymous code block called from the top level.
+       (Note that it is not possible to run the SQL
+       commands <command>COMMIT</command> or <command>ROLLBACK</command>
+       via <function>spi_exec_query</function> or similar.  It has to be done
+       using these functions.)  After a transaction is ended, a new
+       transaction is automatically started, so there is no separate function
+       for that.
+      </para>
+
+      <para>
+       Here is an example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+CALL transaction_test1();
+</programlisting>
+      </para>
+     </listitem>
+    </varlistentry>
    </variablelist>
  </sect2>
 
diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml
index 7d23ed437e..4e0334c530 100644
--- a/doc/src/sgml/plpgsql.sgml
+++ b/doc/src/sgml/plpgsql.sgml
@@ -3449,6 +3449,43 @@ <title>Looping Through a Cursor's Result</title>
 
   </sect1>
 
+  <sect1 id="plpgsql-transactions">
+   <title>Transaction Management</title>
+
+   <para>
+    In procedures invoked by the <command>CALL</command> command from the top
+    level as well as in anonymous code blocks called from the top level, it is
+    possible to end transactions using the commands <command>COMMIT</command>
+    and <command>ROLLBACK</command>.  A new transaction is started
+    automatically after a transaction is ended using these commands, so there
+    is no separate <command>START TRANSACTION</command> command.  (And of
+    course, <command>BEGIN</command> and <command>END</command> have different
+    meanings in PL/pgSQL.)
+   </para>
+
+   <para>
+    Here is a simple example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+CALL transaction_test1();
+</programlisting>
+   </para>
+  </sect1>
+
   <sect1 id="plpgsql-errors-and-messages">
    <title>Errors and Messages</title>
 
@@ -5432,14 +5469,13 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
 <programlisting>
 CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id IN INTEGER) IS
     a_running_job_count INTEGER;
-    PRAGMA AUTONOMOUS_TRANSACTION; -- <co id="co.plpgsql-porting-pragma"/>
 BEGIN
-    LOCK TABLE cs_jobs IN EXCLUSIVE MODE; -- <co id="co.plpgsql-porting-locktable"/>
+    LOCK TABLE cs_jobs IN EXCLUSIVE MODE;
 
     SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL;
 
     IF a_running_job_count &gt; 0 THEN
-        COMMIT; -- free lock <co id="co.plpgsql-porting-commit"/>
+        COMMIT; -- free lock
         raise_application_error(-20000,
                  'Unable to create a new job: a job is currently running.');
     END IF;
@@ -5459,45 +5495,11 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
 </programlisting>
    </para>
 
-   <para>
-    Procedures like this can easily be converted into <productname>PostgreSQL</productname>
-    functions returning <type>void</type>. This procedure in
-    particular is interesting because it can teach us some things:
-
-    <calloutlist>
-     <callout arearefs="co.plpgsql-porting-pragma">
-      <para>
-       There is no <literal>PRAGMA</literal> statement in <productname>PostgreSQL</productname>.
-      </para>
-     </callout>
-
-     <callout arearefs="co.plpgsql-porting-locktable">
-      <para>
-       If you do a <command>LOCK TABLE</command> in <application>PL/pgSQL</application>,
-       the lock will not be released until the calling transaction is
-       finished.
-      </para>
-     </callout>
-
-     <callout arearefs="co.plpgsql-porting-commit">
-      <para>
-       You cannot issue <command>COMMIT</command> in a
-       <application>PL/pgSQL</application> function.  The function is
-       running within some outer transaction and so <command>COMMIT</command>
-       would imply terminating the function's execution.  However, in
-       this particular case it is not necessary anyway, because the lock
-       obtained by the <command>LOCK TABLE</command> will be released when
-       we raise an error.
-      </para>
-     </callout>
-    </calloutlist>
-   </para>
-
    <para>
     This is how we could port this procedure to <application>PL/pgSQL</application>:
 
 <programlisting>
-CREATE OR REPLACE FUNCTION cs_create_job(v_job_id integer) RETURNS void AS $$
+CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id integer) AS $$
 DECLARE
     a_running_job_count integer;
 BEGIN
@@ -5506,6 +5508,7 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
     SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL;
 
     IF a_running_job_count &gt; 0 THEN
+        COMMIT; -- free lock
         RAISE EXCEPTION 'Unable to create a new job: a job is currently running'; -- <co id="co.plpgsql-porting-raise"/>
     END IF;
 
@@ -5518,6 +5521,7 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
         WHEN unique_violation THEN -- <co id="co.plpgsql-porting-exception"/>
             -- don't worry if it already exists
     END;
+    COMMIT;
 END;
 $$ LANGUAGE plpgsql;
 </programlisting>
@@ -5541,12 +5545,6 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
       </para>
      </callout>
     </calloutlist>
-
-    The main functional difference between this procedure and the
-    Oracle equivalent is that the exclusive lock on the <literal>cs_jobs</literal>
-    table will be held until the calling transaction completes.  Also, if
-    the caller later aborts (for example due to an error), the effects of
-    this procedure will be rolled back.
    </para>
    </example>
   </sect2>
diff --git a/doc/src/sgml/plpython.sgml b/doc/src/sgml/plpython.sgml
index 0dbeee1fa2..3f2e141085 100644
--- a/doc/src/sgml/plpython.sgml
+++ b/doc/src/sgml/plpython.sgml
@@ -1370,6 +1370,40 @@ <title>Older Python Versions</title>
   </sect2>
  </sect1>
 
+ <sect1 id="plpython-transactions">
+  <title>Transaction Management</title>
+
+  <para>
+   In a procedure called from the top level or an anonymous code block called
+   from the top level it is possible to control transactions.  To commit the
+   current transaction, call <literal>plpy.commit()</literal>.  To roll back
+   the current transaction, call <literal>plpy.rollback()</literal>.  (Note
+   that it is not possible to run the SQL commands <command>COMMIT</command>
+   or <command>ROLLBACK</command> via <function>plpy.execute</function> or
+   similar.  It has to be done using these functions.)  After a transaction is
+   ended, a new transaction is automatically started, so there is no separate
+   function for that.
+  </para>
+
+  <para>
+   Here is an example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+CALL transaction_test1();
+</programlisting>
+  </para>
+ </sect1>
+
  <sect1 id="plpython-util">
   <title>Utility Functions</title>
   <para>
diff --git a/doc/src/sgml/pltcl.sgml b/doc/src/sgml/pltcl.sgml
index 8018783b0a..de12b20a73 100644
--- a/doc/src/sgml/pltcl.sgml
+++ b/doc/src/sgml/pltcl.sgml
@@ -1002,6 +1002,43 @@ <title>Explicit Subtransactions in PL/Tcl</title>
     </para>
    </sect1>
 
+   <sect1 id="pltcl-transactions">
+    <title>Transaction Management</title>
+
+    <para>
+     In a procedure called from the top level or an anonymous code block
+     called from the top level it is possible to control transactions.  To
+     commit the current transaction, call the <literal>commit</literal>
+     command.  To roll back the current transaction, call
+     the <literal>rollback</literal> command.  (Note that it is not possible
+     to run the SQL commands <command>COMMIT</command>
+     or <command>ROLLBACK</command> via <function>spi_exec</function> or
+     similar.  It has to be done using these functions.)  After a transaction
+     is ended, a new transaction is automatically started, so there is no
+     separate command for that.
+    </para>
+
+    <para>
+     Here is an example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i &lt; 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+
+CALL transaction_test1();
+</programlisting>
+    </para>
+   </sect1>
+
    <sect1 id="pltcl-config">
     <title>PL/Tcl Configuration</title>
 
diff --git a/doc/src/sgml/spi.sgml b/doc/src/sgml/spi.sgml
index 350f0863e9..6df8f8368b 100644
--- a/doc/src/sgml/spi.sgml
+++ b/doc/src/sgml/spi.sgml
@@ -4325,6 +4325,225 @@ <title>Return Value</title>
 
  </sect1>
 
+ <sect1 id="spi-transaction">
+  <title>Transaction Management</title>
+
+  <para>
+   It is not possible to run transaction control commands such
+   as <command>COMMIT</command> and <command>ROLLBACK</command> through SPI
+   functions such as <function>SPI_execute</function>.  There are, however,
+   separate interface functions that allow transaction control through SPI.
+  </para>
+
+  <para>
+   It is not generally safe and sensible to start and end transactions in
+   arbitrary user-defined SQL-callable functions without taking into account
+   the context in which they are called.  For example, a transaction boundary
+   in the middle of a function that is part of a complex SQL expression that
+   is part of some SQL command will probably result in obscure internal errors
+   or crashes.  The interface functions presented here are primarily intended
+   to be used by procedural language implementations to support transaction
+   management in procedures that are invoked by the <command>CALL</command>
+   command, taking the context of the <command>CALL</command> invocation into
+   account.  SPI procedures implemented in C can implement the same logic, but
+   the details of that are beyond the scope of this documentation.
+  </para>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-commit">
+ <indexterm><primary>SPI_commit</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_commit</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_commit</refname>
+  <refpurpose>commit the current transaction</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+int SPI_commit(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_commit</function> commits the current transaction.  It is
+   approximately equivalent to running the SQL
+   command <command>COMMIT</command>.  After a transaction is committed, a new
+   transaction has to be started
+   using <function>SPI_start_transaction</function> before further database
+   actions can be executed.
+  </para>
+
+  <para>
+   Before this function can be
+   executed, <function>SPI_set_nonatomic</function> has to be called for the
+   current SPI connection.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>Return Value</title>
+
+  <para>
+   0 on success
+  </para>
+ </refsect1>
+</refentry>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-rollback">
+ <indexterm><primary>SPI_rollback</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_rollback</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_rollback</refname>
+  <refpurpose>abort the current transaction</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+int SPI_rollback(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_rollback</function> rolls back the current transaction.  It
+   is approximately equivalent to running the SQL
+   command <command>ROLLBACK</command>.  After a transaction is rolled back, a
+   new transaction has to be started
+   using <function>SPI_start_transaction</function> before further database
+   actions can be executed.
+  </para>
+
+  <para>
+   Before this function can be
+   executed, <function>SPI_set_nonatomic</function> has to be called for the
+   current SPI connection.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>Return Value</title>
+
+  <para>
+   0 on success
+  </para>
+ </refsect1>
+</refentry>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-set-nonatomic">
+ <indexterm><primary>SPI_set_nonatomic</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_set_nonatomic</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_set_nonatomic</refname>
+  <refpurpose>makes current SPI connection nonatomic</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+int SPI_set_nonatomic(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_set_nonatomic</function> sets the current SPI connection to
+   be <firstterm>nonatomic</firstterm>, which means that transaction control
+   calls <function>SPI_commit</function>, <function>SPI_rollback</function>,
+   and <function>SPI_start_transaction</function> are allowed.  Otherwise,
+   calling these functions will result in an immediate
+   error.  <function>SPI_set_nonatomic</function> has to be called
+   after <function>SPI_connect</function> and its effects are canceled by the
+   corresponding <function>SPI_finish</function>, but it can be called at any
+   point in between.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>Return Value</title>
+
+  <para>
+   0 on success
+  </para>
+ </refsect1>
+</refentry>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-start-transaction">
+ <indexterm><primary>SPI_start_transaction</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_start_transaction</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_start_transaction</refname>
+  <refpurpose>start a new transaction</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+int SPI_start_transaction(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_start_transaction</function> starts a new transaction.  It
+   can only be called after <function>SPI_commit</function>
+   or <function>SPI_rollback</function>, as there is no transaction active at
+   that point.  Normally, when an SPI procedure is called, there is already a
+   transaction active, so attempting to start another one before closing out
+   the current one will result in an error.
+  </para>
+
+  <para>
+   Before this function can be
+   executed, <function>SPI_set_nonatomic</function> has to be called for the
+   current SPI connection.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>Return Value</title>
+
+  <para>
+   0 on success
+  </para>
+ </refsect1>
+</refentry>
+
+ </sect1>
+
  <sect1 id="spi-visibility">
   <title>Visibility of Data Changes</title>
 
diff --git a/src/backend/commands/functioncmds.c b/src/backend/commands/functioncmds.c
index 2a9c90133d..81b34522c0 100644
--- a/src/backend/commands/functioncmds.c
+++ b/src/backend/commands/functioncmds.c
@@ -65,6 +65,7 @@
 #include "utils/fmgroids.h"
 #include "utils/guc.h"
 #include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/rel.h"
 #include "utils/syscache.h"
 #include "utils/tqual.h"
@@ -2138,7 +2139,7 @@ IsThereFunctionInNamespace(const char *proname, int pronargs,
  *		Execute inline procedural-language code
  */
 void
-ExecuteDoStmt(DoStmt *stmt)
+ExecuteDoStmt(DoStmt *stmt, bool atomic)
 {
 	InlineCodeBlock *codeblock = makeNode(InlineCodeBlock);
 	ListCell   *arg;
@@ -2200,6 +2201,7 @@ ExecuteDoStmt(DoStmt *stmt)
 	codeblock->langOid = HeapTupleGetOid(languageTuple);
 	languageStruct = (Form_pg_language) GETSTRUCT(languageTuple);
 	codeblock->langIsTrusted = languageStruct->lanpltrusted;
+	codeblock->atomic = atomic;
 
 	if (languageStruct->lanpltrusted)
 	{
@@ -2236,9 +2238,28 @@ ExecuteDoStmt(DoStmt *stmt)
 
 /*
  * Execute CALL statement
+ *
+ * Inside a top-level CALL statement, transaction-terminating commands such as
+ * COMMIT or a PL-specific equivalent are allowed.  The terminology in the SQL
+ * standard is that CALL establishes a non-atomic execution context.  Most
+ * other commands establish an atomic execution context, in which transaction
+ * control actions are not allowed.  If there are nested executions of CALL,
+ * we want to track the execution context recursively, so that the nested
+ * CALLs can also do transaction control.  Note, however, that for example in
+ * CALL -> SELECT -> CALL, the second call cannot do transaction control,
+ * because the SELECT in between establishes an atomic execution context.
+ *
+ * So when ExecuteCallStmt() is called from the top level, we pass in atomic =
+ * false (recall that that means transactions = yes).  We then create a
+ * CallContext node with content atomic = false, which is passed in the
+ * fcinfo->context field to the procedure invocation.  The language
+ * implementation should then take appropriate measures to allow or prevent
+ * transaction commands based on that information, e.g., call
+ * SPI_set_nonatomic().  The language should also pass on the atomic flag to
+ * any recursive invocations to CALL.
  */
 void
-ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
+ExecuteCallStmt(ParseState *pstate, CallStmt *stmt, bool atomic)
 {
 	List	   *targs;
 	ListCell   *lc;
@@ -2249,6 +2270,7 @@ ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
 	AclResult   aclresult;
 	FmgrInfo	flinfo;
 	FunctionCallInfoData fcinfo;
+	CallContext *callcontext;
 
 	targs = NIL;
 	foreach(lc, stmt->funccall->args)
@@ -2284,8 +2306,10 @@ ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
 							   FUNC_MAX_ARGS,
 							   FUNC_MAX_ARGS)));
 
+	callcontext = makeNode(CallContext);
+	callcontext->atomic = atomic;
 	fmgr_info(fexpr->funcid, &flinfo);
-	InitFunctionCallInfoData(fcinfo, &flinfo, nargs, fexpr->inputcollid, NULL, NULL);
+	InitFunctionCallInfoData(fcinfo, &flinfo, nargs, fexpr->inputcollid, (Node *) callcontext, NULL);
 
 	i = 0;
 	foreach (lc, fexpr->args)
diff --git a/src/backend/executor/spi.c b/src/backend/executor/spi.c
index 2da1cac3e2..14a59e722f 100644
--- a/src/backend/executor/spi.c
+++ b/src/backend/executor/spi.c
@@ -92,7 +92,7 @@ SPI_connect(void)
 			elog(ERROR, "SPI stack corrupted");
 		newdepth = 16;
 		_SPI_stack = (_SPI_connection *)
-			MemoryContextAlloc(TopTransactionContext,
+			MemoryContextAlloc(TopMemoryContext,
 							   newdepth * sizeof(_SPI_connection));
 		_SPI_stack_depth = newdepth;
 	}
@@ -124,6 +124,7 @@ SPI_connect(void)
 	_SPI_current->execCxt = NULL;
 	_SPI_current->connectSubid = GetCurrentSubTransactionId();
 	_SPI_current->queryEnv = NULL;
+	_SPI_current->atomic = true;	/* until told otherwise */
 
 	/*
 	 * Create memory contexts for this procedure
@@ -133,10 +134,10 @@ SPI_connect(void)
 	 * Perhaps CurTransactionContext would do?	For now it doesn't matter
 	 * because we clean up explicitly in AtEOSubXact_SPI().
 	 */
-	_SPI_current->procCxt = AllocSetContextCreate(TopTransactionContext,
+	_SPI_current->procCxt = AllocSetContextCreate(PortalContext,
 												  "SPI Proc",
 												  ALLOCSET_DEFAULT_SIZES);
-	_SPI_current->execCxt = AllocSetContextCreate(TopTransactionContext,
+	_SPI_current->execCxt = AllocSetContextCreate(_SPI_current->procCxt,
 												  "SPI Exec",
 												  ALLOCSET_DEFAULT_SIZES);
 	/* ... and switch to procedure's context */
@@ -145,6 +146,17 @@ SPI_connect(void)
 	return SPI_OK_CONNECT;
 }
 
+int
+SPI_set_nonatomic(void)
+{
+	if (_SPI_current == NULL)
+		return SPI_ERROR_UNCONNECTED;
+
+	_SPI_current->atomic = false;
+
+	return SPI_OK_CONNECT;
+}
+
 int
 SPI_finish(void)
 {
@@ -158,8 +170,6 @@ SPI_finish(void)
 	MemoryContextSwitchTo(_SPI_current->savedcxt);
 
 	/* Release memory used in procedure call (including tuptables) */
-	MemoryContextDelete(_SPI_current->execCxt);
-	_SPI_current->execCxt = NULL;
 	MemoryContextDelete(_SPI_current->procCxt);
 	_SPI_current->procCxt = NULL;
 
@@ -181,12 +191,67 @@ SPI_finish(void)
 	return SPI_OK_FINISH;
 }
 
+int
+SPI_start_transaction(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	StartTransactionCommand();
+	MemoryContextSwitchTo(oldcontext);
+	return 0;
+}
+
+int
+SPI_commit(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	if (_SPI_current->atomic)
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("invalid transaction termination")));
+
+	_SPI_current->internal_xact = true;
+
+	if (ActiveSnapshotSet())
+		PopActiveSnapshot();
+	CommitTransactionCommand();
+	MemoryContextSwitchTo(oldcontext);
+
+	_SPI_current->internal_xact = false;
+
+	return 0;
+}
+
+int
+SPI_rollback(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	if (_SPI_current->atomic)
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("invalid transaction termination")));
+
+	_SPI_current->internal_xact = true;
+
+	AbortCurrentTransaction();
+	MemoryContextSwitchTo(oldcontext);
+
+	_SPI_current->internal_xact = false;
+
+	return 0;
+}
+
 /*
  * Clean up SPI state at transaction commit or abort.
  */
 void
 AtEOXact_SPI(bool isCommit)
 {
+	if (_SPI_current && _SPI_current->internal_xact)
+		return;
+
 	/*
 	 * Note that memory contexts belonging to SPI stack entries will be freed
 	 * automatically, so we can ignore them here.  We just need to restore our
@@ -224,21 +289,10 @@ AtEOSubXact_SPI(bool isCommit, SubTransactionId mySubid)
 		if (connection->connectSubid != mySubid)
 			break;				/* couldn't be any underneath it either */
 
-		found = true;
+		if (connection->internal_xact)
+			break;
 
-		/*
-		 * Release procedure memory explicitly (see note in SPI_connect)
-		 */
-		if (connection->execCxt)
-		{
-			MemoryContextDelete(connection->execCxt);
-			connection->execCxt = NULL;
-		}
-		if (connection->procCxt)
-		{
-			MemoryContextDelete(connection->procCxt);
-			connection->procCxt = NULL;
-		}
+		found = true;
 
 		/*
 		 * Pop the stack entry and reset global variables.  Unlike
diff --git a/src/backend/tcop/utility.c b/src/backend/tcop/utility.c
index 4da1f8f643..b20861066b 100644
--- a/src/backend/tcop/utility.c
+++ b/src/backend/tcop/utility.c
@@ -529,7 +529,7 @@ standard_ProcessUtility(PlannedStmt *pstmt,
 			break;
 
 		case T_DoStmt:
-			ExecuteDoStmt((DoStmt *) parsetree);
+			ExecuteDoStmt((DoStmt *) parsetree, context != PROCESS_UTILITY_TOPLEVEL);
 			break;
 
 		case T_CreateTableSpaceStmt:
@@ -658,7 +658,7 @@ standard_ProcessUtility(PlannedStmt *pstmt,
 			break;
 
 		case T_CallStmt:
-			ExecuteCallStmt(pstate, castNode(CallStmt, parsetree));
+			ExecuteCallStmt(pstate, castNode(CallStmt, parsetree), context != PROCESS_UTILITY_TOPLEVEL);
 			break;
 
 		case T_ClusterStmt:
diff --git a/src/backend/utils/mmgr/portalmem.c b/src/backend/utils/mmgr/portalmem.c
index d03b779407..1b217c312a 100644
--- a/src/backend/utils/mmgr/portalmem.c
+++ b/src/backend/utils/mmgr/portalmem.c
@@ -736,11 +736,8 @@ PreCommit_Portals(bool isPrepare)
 /*
  * Abort processing for portals.
  *
- * At this point we reset "active" status and run the cleanup hook if
- * present, but we can't release the portal's memory until the cleanup call.
- *
- * The reason we need to reset active is so that we can replace the unnamed
- * portal, else we'll fail to execute ROLLBACK when it arrives.
+ * At this point we run the cleanup hook if present, but we can't release the
+ * portal's memory until the cleanup call.
  */
 void
 AtAbort_Portals(void)
@@ -754,17 +751,6 @@ AtAbort_Portals(void)
 	{
 		Portal		portal = hentry->portal;
 
-		/*
-		 * See similar code in AtSubAbort_Portals().  This would fire if code
-		 * orchestrating multiple top-level transactions within a portal, such
-		 * as VACUUM, caught errors and continued under the same portal with a
-		 * fresh transaction.  No part of core PostgreSQL functions that way.
-		 * XXX Such code would wish the portal to remain ACTIVE, as in
-		 * PreCommit_Portals().
-		 */
-		if (portal->status == PORTAL_ACTIVE)
-			MarkPortalFailed(portal);
-
 		/*
 		 * Do nothing else to cursors held over from a previous transaction.
 		 */
@@ -799,14 +785,6 @@ AtAbort_Portals(void)
 		 * PortalDrop.
 		 */
 		portal->resowner = NULL;
-
-		/*
-		 * Although we can't delete the portal data structure proper, we can
-		 * release any memory in subsidiary contexts, such as executor state.
-		 * The cleanup hook was the last thing that might have needed data
-		 * there.
-		 */
-		MemoryContextDeleteChildren(PortalGetHeapMemory(portal));
 	}
 }
 
@@ -826,6 +804,19 @@ AtCleanup_Portals(void)
 	{
 		Portal		portal = hentry->portal;
 
+		/*
+		 * Do not touch active portals --- this can only happen in the case of
+		 * a multi-transaction command.
+		 *
+		 * Note however that any resource owner attached to such a portal is
+		 * still going to go away, so don't leave a dangling pointer.
+		 */
+		if (portal->status == PORTAL_ACTIVE)
+		{
+			portal->resowner = NULL;
+			continue;
+		}
+
 		/* Do nothing to cursors held over from a previous transaction */
 		if (portal->createSubid == InvalidSubTransactionId)
 		{
diff --git a/src/include/commands/defrem.h b/src/include/commands/defrem.h
index 52cbf61ccb..b03f5b6a95 100644
--- a/src/include/commands/defrem.h
+++ b/src/include/commands/defrem.h
@@ -58,8 +58,8 @@ extern ObjectAddress CreateTransform(CreateTransformStmt *stmt);
 extern void DropTransformById(Oid transformOid);
 extern void IsThereFunctionInNamespace(const char *proname, int pronargs,
 						   oidvector *proargtypes, Oid nspOid);
-extern void ExecuteDoStmt(DoStmt *stmt);
-extern void ExecuteCallStmt(ParseState *pstate, CallStmt *stmt);
+extern void ExecuteDoStmt(DoStmt *stmt, bool atomic);
+extern void ExecuteCallStmt(ParseState *pstate, CallStmt *stmt, bool atomic);
 extern Oid	get_cast_oid(Oid sourcetypeid, Oid targettypeid, bool missing_ok);
 extern Oid	get_transform_oid(Oid type_id, Oid lang_id, bool missing_ok);
 extern void interpret_function_parameter_list(ParseState *pstate,
diff --git a/src/include/executor/spi.h b/src/include/executor/spi.h
index acade7e92e..e38158c54e 100644
--- a/src/include/executor/spi.h
+++ b/src/include/executor/spi.h
@@ -78,6 +78,7 @@ extern PGDLLIMPORT SPITupleTable *SPI_tuptable;
 extern PGDLLIMPORT int SPI_result;
 
 extern int	SPI_connect(void);
+extern int	SPI_set_nonatomic(void);
 extern int	SPI_finish(void);
 extern int	SPI_execute(const char *src, bool read_only, long tcount);
 extern int SPI_execute_plan(SPIPlanPtr plan, Datum *Values, const char *Nulls,
@@ -156,6 +157,10 @@ extern int	SPI_register_relation(EphemeralNamedRelation enr);
 extern int	SPI_unregister_relation(const char *name);
 extern int	SPI_register_trigger_data(TriggerData *tdata);
 
+extern int	SPI_start_transaction(void);
+extern int	SPI_commit(void);
+extern int	SPI_rollback(void);
+
 extern void AtEOXact_SPI(bool isCommit);
 extern void AtEOSubXact_SPI(bool isCommit, SubTransactionId mySubid);
 
diff --git a/src/include/executor/spi_priv.h b/src/include/executor/spi_priv.h
index 8fae755418..9dc8af22e4 100644
--- a/src/include/executor/spi_priv.h
+++ b/src/include/executor/spi_priv.h
@@ -36,6 +36,10 @@ typedef struct
 	MemoryContext savedcxt;		/* context of SPI_connect's caller */
 	SubTransactionId connectSubid;	/* ID of connecting subtransaction */
 	QueryEnvironment *queryEnv; /* query environment setup for SPI level */
+
+	/* transaction management support */
+	bool		atomic;			/* atomic execution context, does not allow transactions */
+	bool		internal_xact;	/* SPI-managed transaction boundary, skip cleanup */
 } _SPI_connection;
 
 /*
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index c5b5115f5b..6dcd51e958 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -500,7 +500,8 @@ typedef enum NodeTag
 	T_FdwRoutine,				/* in foreign/fdwapi.h */
 	T_IndexAmRoutine,			/* in access/amapi.h */
 	T_TsmRoutine,				/* in access/tsmapi.h */
-	T_ForeignKeyCacheInfo		/* in utils/rel.h */
+	T_ForeignKeyCacheInfo,		/* in utils/rel.h */
+	T_CallContext				/* in nodes/parsenodes.h */
 } NodeTag;
 
 /*
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 2eaa6b2774..cb1afd68f8 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2803,6 +2803,7 @@ typedef struct InlineCodeBlock
 	char	   *source_text;	/* source text of anonymous code block */
 	Oid			langOid;		/* OID of selected language */
 	bool		langIsTrusted;	/* trusted property of the language */
+	bool		atomic;			/* atomic execution context */
 } InlineCodeBlock;
 
 /* ----------------------
@@ -2815,6 +2816,12 @@ typedef struct CallStmt
 	FuncCall   *funccall;
 } CallStmt;
 
+typedef struct CallContext
+{
+	NodeTag		type;
+	bool		atomic;
+} CallContext;
+
 /* ----------------------
  *		Alter Object Rename Statement
  * ----------------------
diff --git a/src/pl/plperl/GNUmakefile b/src/pl/plperl/GNUmakefile
index b829027d05..933abb47c4 100644
--- a/src/pl/plperl/GNUmakefile
+++ b/src/pl/plperl/GNUmakefile
@@ -55,7 +55,7 @@ endif # win32
 SHLIB_LINK = $(perl_embed_ldflags)
 
 REGRESS_OPTS = --dbname=$(PL_TESTDB) --load-extension=plperl  --load-extension=plperlu
-REGRESS = plperl plperl_lc plperl_trigger plperl_shared plperl_elog plperl_util plperl_init plperlu plperl_array plperl_call
+REGRESS = plperl plperl_lc plperl_trigger plperl_shared plperl_elog plperl_util plperl_init plperlu plperl_array plperl_call plperl_transaction
 # if Perl can support two interpreters in one backend,
 # test plperl-and-plperlu cases
 ifneq ($(PERL),)
diff --git a/src/pl/plperl/SPI.xs b/src/pl/plperl/SPI.xs
index d9e6f579d4..dc9ddedc8f 100644
--- a/src/pl/plperl/SPI.xs
+++ b/src/pl/plperl/SPI.xs
@@ -17,6 +17,7 @@
 #define PG_NEED_PERL_XSUB_H
 #include "plperl.h"
 #include "plperl_helpers.h"
+#include "executor/spi.h"
 
 
 MODULE = PostgreSQL::InServer::SPI PREFIX = spi_
@@ -152,6 +153,17 @@ spi_spi_cursor_close(sv)
 		plperl_spi_cursor_close(cursor);
 		pfree(cursor);
 
+void
+spi_spi_commit()
+	CODE:
+		SPI_commit();
+		SPI_start_transaction();
+
+void
+spi_spi_rollback()
+	CODE:
+		SPI_rollback();
+		SPI_start_transaction();
 
 BOOT:
     items = 0;  /* avoid 'unused variable' warning */
diff --git a/src/pl/plperl/expected/plperl_transaction.out b/src/pl/plperl/expected/plperl_transaction.out
new file mode 100644
index 0000000000..f7378ce600
--- /dev/null
+++ b/src/pl/plperl/expected/plperl_transaction.out
@@ -0,0 +1,94 @@
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+DO
+LANGUAGE plperl
+$$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+return 1;
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/Perl function "transaction_test2"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query("CALL transaction_test1()");
+return 1;
+$$;
+-- FIXME
+--SELECT transaction_test3();
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query('DO LANGUAGE plperl $x$ spi_commit(); $x$');
+return 1;
+$$;
+-- FIXME
+--SELECT transaction_test4();
+DROP TABLE test1;
diff --git a/src/pl/plperl/plperl.c b/src/pl/plperl/plperl.c
index 9f5313235f..68592033f7 100644
--- a/src/pl/plperl/plperl.c
+++ b/src/pl/plperl/plperl.c
@@ -1931,6 +1931,8 @@ plperl_inline_handler(PG_FUNCTION_ARGS)
 
 		if (SPI_connect() != SPI_OK_CONNECT)
 			elog(ERROR, "could not connect to SPI manager");
+		if (!codeblock->atomic)
+			SPI_set_nonatomic();
 
 		select_perl_context(desc.lanpltrusted);
 
@@ -2409,6 +2411,10 @@ plperl_func_handler(PG_FUNCTION_ARGS)
 	current_call_data->prodesc = prodesc;
 	increment_prodesc_refcount(prodesc);
 
+	if (prodesc->result_oid == InvalidOid &&
+		!castNode(CallContext, fcinfo->context)->atomic)
+		SPI_set_nonatomic();
+
 	/* Set a callback for error reporting */
 	pl_error_context.callback = plperl_exec_callback;
 	pl_error_context.previous = error_context_stack;
diff --git a/src/pl/plperl/sql/plperl_transaction.sql b/src/pl/plperl/sql/plperl_transaction.sql
new file mode 100644
index 0000000000..5f15691cfc
--- /dev/null
+++ b/src/pl/plperl/sql/plperl_transaction.sql
@@ -0,0 +1,88 @@
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+DO
+LANGUAGE plperl
+$$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+return 1;
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query("CALL transaction_test1()");
+return 1;
+$$;
+
+-- FIXME
+--SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query('DO LANGUAGE plperl $x$ spi_commit(); $x$');
+return 1;
+$$;
+
+-- FIXME
+--SELECT transaction_test4();
+
+
+DROP TABLE test1;
diff --git a/src/pl/plpgsql/src/pl_exec.c b/src/pl/plpgsql/src/pl_exec.c
index ec480cb0ba..97ee299136 100644
--- a/src/pl/plpgsql/src/pl_exec.c
+++ b/src/pl/plpgsql/src/pl_exec.c
@@ -215,6 +215,10 @@ static int exec_stmt_dynexecute(PLpgSQL_execstate *estate,
 					 PLpgSQL_stmt_dynexecute *stmt);
 static int exec_stmt_dynfors(PLpgSQL_execstate *estate,
 				  PLpgSQL_stmt_dynfors *stmt);
+static int exec_stmt_commit(PLpgSQL_execstate *estate,
+				PLpgSQL_stmt_commit *stmt);
+static int exec_stmt_rollback(PLpgSQL_execstate *estate,
+				PLpgSQL_stmt_rollback *stmt);
 
 static void plpgsql_estate_setup(PLpgSQL_execstate *estate,
 					 PLpgSQL_function *func,
@@ -1652,6 +1656,14 @@ exec_stmt(PLpgSQL_execstate *estate, PLpgSQL_stmt *stmt)
 			rc = exec_stmt_close(estate, (PLpgSQL_stmt_close *) stmt);
 			break;
 
+		case PLPGSQL_STMT_COMMIT:
+			rc = exec_stmt_commit(estate, (PLpgSQL_stmt_commit *) stmt);
+			break;
+
+		case PLPGSQL_STMT_ROLLBACK:
+			rc = exec_stmt_rollback(estate, (PLpgSQL_stmt_rollback *) stmt);
+			break;
+
 		default:
 			estate->err_stmt = save_estmt;
 			elog(ERROR, "unrecognized cmdtype: %d", stmt->cmd_type);
@@ -4356,6 +4368,39 @@ exec_stmt_close(PLpgSQL_execstate *estate, PLpgSQL_stmt_close *stmt)
 	return PLPGSQL_RC_OK;
 }
 
+/*
+ * exec_stmt_commit
+ *
+ * Commit the transaction.
+ */
+static int
+exec_stmt_commit(PLpgSQL_execstate *estate, PLpgSQL_stmt_commit *stmt)
+{
+	SPI_commit();
+	SPI_start_transaction();
+
+	estate->simple_eval_estate = NULL;
+	plpgsql_create_econtext(estate);
+
+	return PLPGSQL_RC_OK;
+}
+
+/*
+ * exec_stmt_rollback
+ *
+ * Abort the transaction.
+ */
+static int
+exec_stmt_rollback(PLpgSQL_execstate *estate, PLpgSQL_stmt_rollback *stmt)
+{
+	SPI_rollback();
+	SPI_start_transaction();
+
+	estate->simple_eval_estate = NULL;
+	plpgsql_create_econtext(estate);
+
+	return PLPGSQL_RC_OK;
+}
 
 /* ----------
  * exec_assign_expr			Put an expression's result into a variable.
@@ -6857,8 +6902,7 @@ plpgsql_xact_cb(XactEvent event, void *arg)
 	 */
 	if (event == XACT_EVENT_COMMIT || event == XACT_EVENT_PREPARE)
 	{
-		/* Shouldn't be any econtext stack entries left at commit */
-		Assert(simple_econtext_stack == NULL);
+		simple_econtext_stack = NULL;
 
 		if (shared_simple_eval_estate)
 			FreeExecutorState(shared_simple_eval_estate);
diff --git a/src/pl/plpgsql/src/pl_funcs.c b/src/pl/plpgsql/src/pl_funcs.c
index 23f54e1c21..a3a45916d1 100644
--- a/src/pl/plpgsql/src/pl_funcs.c
+++ b/src/pl/plpgsql/src/pl_funcs.c
@@ -284,6 +284,10 @@ plpgsql_stmt_typename(PLpgSQL_stmt *stmt)
 			return "CLOSE";
 		case PLPGSQL_STMT_PERFORM:
 			return "PERFORM";
+		case PLPGSQL_STMT_COMMIT:
+			return "COMMIT";
+		case PLPGSQL_STMT_ROLLBACK:
+			return "ROLLBACK";
 	}
 
 	return "unknown";
@@ -363,6 +367,8 @@ static void free_open(PLpgSQL_stmt_open *stmt);
 static void free_fetch(PLpgSQL_stmt_fetch *stmt);
 static void free_close(PLpgSQL_stmt_close *stmt);
 static void free_perform(PLpgSQL_stmt_perform *stmt);
+static void free_commit(PLpgSQL_stmt_commit *stmt);
+static void free_rollback(PLpgSQL_stmt_rollback *stmt);
 static void free_expr(PLpgSQL_expr *expr);
 
 
@@ -443,6 +449,12 @@ free_stmt(PLpgSQL_stmt *stmt)
 		case PLPGSQL_STMT_PERFORM:
 			free_perform((PLpgSQL_stmt_perform *) stmt);
 			break;
+		case PLPGSQL_STMT_COMMIT:
+			free_commit((PLpgSQL_stmt_commit *) stmt);
+			break;
+		case PLPGSQL_STMT_ROLLBACK:
+			free_rollback((PLpgSQL_stmt_rollback *) stmt);
+			break;
 		default:
 			elog(ERROR, "unrecognized cmd_type: %d", stmt->cmd_type);
 			break;
@@ -590,6 +602,16 @@ free_perform(PLpgSQL_stmt_perform *stmt)
 	free_expr(stmt->expr);
 }
 
+static void
+free_commit(PLpgSQL_stmt_commit *stmt)
+{
+}
+
+static void
+free_rollback(PLpgSQL_stmt_rollback *stmt)
+{
+}
+
 static void
 free_exit(PLpgSQL_stmt_exit *stmt)
 {
@@ -777,6 +799,8 @@ static void dump_fetch(PLpgSQL_stmt_fetch *stmt);
 static void dump_cursor_direction(PLpgSQL_stmt_fetch *stmt);
 static void dump_close(PLpgSQL_stmt_close *stmt);
 static void dump_perform(PLpgSQL_stmt_perform *stmt);
+static void dump_commit(PLpgSQL_stmt_commit *stmt);
+static void dump_rollback(PLpgSQL_stmt_rollback *stmt);
 static void dump_expr(PLpgSQL_expr *expr);
 
 
@@ -867,6 +891,12 @@ dump_stmt(PLpgSQL_stmt *stmt)
 		case PLPGSQL_STMT_PERFORM:
 			dump_perform((PLpgSQL_stmt_perform *) stmt);
 			break;
+		case PLPGSQL_STMT_COMMIT:
+			dump_commit((PLpgSQL_stmt_commit *) stmt);
+			break;
+		case PLPGSQL_STMT_ROLLBACK:
+			dump_rollback((PLpgSQL_stmt_rollback *) stmt);
+			break;
 		default:
 			elog(ERROR, "unrecognized cmd_type: %d", stmt->cmd_type);
 			break;
@@ -1243,6 +1273,20 @@ dump_perform(PLpgSQL_stmt_perform *stmt)
 	printf("\n");
 }
 
+static void
+dump_commit(PLpgSQL_stmt_commit *stmt)
+{
+	dump_ind();
+	printf("COMMIT\n");
+}
+
+static void
+dump_rollback(PLpgSQL_stmt_rollback *stmt)
+{
+	dump_ind();
+	printf("ROLLBACK\n");
+}
+
 static void
 dump_exit(PLpgSQL_stmt_exit *stmt)
 {
diff --git a/src/pl/plpgsql/src/pl_gram.y b/src/pl/plpgsql/src/pl_gram.y
index 94f1f58593..e661750176 100644
--- a/src/pl/plpgsql/src/pl_gram.y
+++ b/src/pl/plpgsql/src/pl_gram.y
@@ -199,6 +199,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %type <stmt>	stmt_return stmt_raise stmt_assert stmt_execsql
 %type <stmt>	stmt_dynexecute stmt_for stmt_perform stmt_getdiag
 %type <stmt>	stmt_open stmt_fetch stmt_move stmt_close stmt_null
+%type <stmt>	stmt_commit stmt_rollback
 %type <stmt>	stmt_case stmt_foreach_a
 
 %type <list>	proc_exceptions
@@ -261,6 +262,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %token <keyword>	K_COLLATE
 %token <keyword>	K_COLUMN
 %token <keyword>	K_COLUMN_NAME
+%token <keyword>	K_COMMIT
 %token <keyword>	K_CONSTANT
 %token <keyword>	K_CONSTRAINT
 %token <keyword>	K_CONSTRAINT_NAME
@@ -326,6 +328,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %token <keyword>	K_RETURN
 %token <keyword>	K_RETURNED_SQLSTATE
 %token <keyword>	K_REVERSE
+%token <keyword>	K_ROLLBACK
 %token <keyword>	K_ROW_COUNT
 %token <keyword>	K_ROWTYPE
 %token <keyword>	K_SCHEMA
@@ -898,6 +901,10 @@ proc_stmt		: pl_block ';'
 						{ $$ = $1; }
 				| stmt_null
 						{ $$ = $1; }
+				| stmt_commit
+						{ $$ = $1; }
+				| stmt_rollback
+						{ $$ = $1; }
 				;
 
 stmt_perform	: K_PERFORM expr_until_semi
@@ -2174,6 +2181,31 @@ stmt_null		: K_NULL ';'
 					}
 				;
 
+stmt_commit		: K_COMMIT ';'
+					{
+						PLpgSQL_stmt_commit *new;
+
+						new = palloc(sizeof(PLpgSQL_stmt_commit));
+						new->cmd_type = PLPGSQL_STMT_COMMIT;
+						new->lineno = plpgsql_location_to_lineno(@1);
+
+						$$ = (PLpgSQL_stmt *)new;
+					}
+				;
+
+stmt_rollback	: K_ROLLBACK ';'
+					{
+						PLpgSQL_stmt_rollback *new;
+
+						new = palloc(sizeof(PLpgSQL_stmt_rollback));
+						new->cmd_type = PLPGSQL_STMT_ROLLBACK;
+						new->lineno = plpgsql_location_to_lineno(@1);
+
+						$$ = (PLpgSQL_stmt *)new;
+					}
+				;
+
+
 cursor_variable	: T_DATUM
 					{
 						/*
@@ -2410,6 +2442,7 @@ unreserved_keyword	:
 				| K_COLLATE
 				| K_COLUMN
 				| K_COLUMN_NAME
+				| K_COMMIT
 				| K_CONSTANT
 				| K_CONSTRAINT
 				| K_CONSTRAINT_NAME
@@ -2461,6 +2494,7 @@ unreserved_keyword	:
 				| K_RETURN
 				| K_RETURNED_SQLSTATE
 				| K_REVERSE
+				| K_ROLLBACK
 				| K_ROW_COUNT
 				| K_ROWTYPE
 				| K_SCHEMA
diff --git a/src/pl/plpgsql/src/pl_handler.c b/src/pl/plpgsql/src/pl_handler.c
index 1ebb7a7b5e..6857b0375e 100644
--- a/src/pl/plpgsql/src/pl_handler.c
+++ b/src/pl/plpgsql/src/pl_handler.c
@@ -255,7 +255,12 @@ plpgsql_call_handler(PG_FUNCTION_ARGS)
 			retval = (Datum) 0;
 		}
 		else
+		{
+			if (func->fn_rettype == InvalidOid &&
+				!castNode(CallContext, fcinfo->context)->atomic)
+				SPI_set_nonatomic();
 			retval = plpgsql_exec_function(func, fcinfo, NULL);
+		}
 	}
 	PG_CATCH();
 	{
@@ -304,6 +309,9 @@ plpgsql_inline_handler(PG_FUNCTION_ARGS)
 	if ((rc = SPI_connect()) != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed: %s", SPI_result_code_string(rc));
 
+	if (!codeblock->atomic)
+		SPI_set_nonatomic();
+
 	/* Compile the anonymous code block */
 	func = plpgsql_compile_inline(codeblock->source_text);
 
diff --git a/src/pl/plpgsql/src/pl_scanner.c b/src/pl/plpgsql/src/pl_scanner.c
index 553be8c93c..a172031db2 100644
--- a/src/pl/plpgsql/src/pl_scanner.c
+++ b/src/pl/plpgsql/src/pl_scanner.c
@@ -106,6 +106,7 @@ static const ScanKeyword unreserved_keywords[] = {
 	PG_KEYWORD("collate", K_COLLATE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("column", K_COLUMN, UNRESERVED_KEYWORD)
 	PG_KEYWORD("column_name", K_COLUMN_NAME, UNRESERVED_KEYWORD)
+	PG_KEYWORD("commit", K_COMMIT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constant", K_CONSTANT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constraint", K_CONSTRAINT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constraint_name", K_CONSTRAINT_NAME, UNRESERVED_KEYWORD)
@@ -158,6 +159,7 @@ static const ScanKeyword unreserved_keywords[] = {
 	PG_KEYWORD("return", K_RETURN, UNRESERVED_KEYWORD)
 	PG_KEYWORD("returned_sqlstate", K_RETURNED_SQLSTATE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("reverse", K_REVERSE, UNRESERVED_KEYWORD)
+	PG_KEYWORD("rollback", K_ROLLBACK, UNRESERVED_KEYWORD)
 	PG_KEYWORD("row_count", K_ROW_COUNT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("rowtype", K_ROWTYPE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("schema", K_SCHEMA, UNRESERVED_KEYWORD)
diff --git a/src/pl/plpgsql/src/plpgsql.h b/src/pl/plpgsql/src/plpgsql.h
index 2b19948562..8494a4374d 100644
--- a/src/pl/plpgsql/src/plpgsql.h
+++ b/src/pl/plpgsql/src/plpgsql.h
@@ -105,7 +105,9 @@ typedef enum PLpgSQL_stmt_type
 	PLPGSQL_STMT_OPEN,
 	PLPGSQL_STMT_FETCH,
 	PLPGSQL_STMT_CLOSE,
-	PLPGSQL_STMT_PERFORM
+	PLPGSQL_STMT_PERFORM,
+	PLPGSQL_STMT_COMMIT,
+	PLPGSQL_STMT_ROLLBACK
 } PLpgSQL_stmt_type;
 
 /*
@@ -433,6 +435,24 @@ typedef struct PLpgSQL_stmt_perform
 	PLpgSQL_expr *expr;
 } PLpgSQL_stmt_perform;
 
+/*
+ * COMMIT statement
+ */
+typedef struct PLpgSQL_stmt_commit
+{
+	PLpgSQL_stmt_type cmd_type;
+	int			lineno;
+} PLpgSQL_stmt_commit;
+
+/*
+ * ROLLBACK statement
+ */
+typedef struct PLpgSQL_stmt_rollback
+{
+	PLpgSQL_stmt_type cmd_type;
+	int			lineno;
+} PLpgSQL_stmt_rollback;
+
 /*
  * GET DIAGNOSTICS item
  */
diff --git a/src/pl/plpython/Makefile b/src/pl/plpython/Makefile
index cc91afebde..d09910835d 100644
--- a/src/pl/plpython/Makefile
+++ b/src/pl/plpython/Makefile
@@ -90,6 +90,7 @@ REGRESS = \
 	plpython_quote \
 	plpython_composite \
 	plpython_subtransaction \
+	plpython_transaction \
 	plpython_drop
 
 REGRESS_PLPYTHON3_MANGLE := $(REGRESS)
diff --git a/src/pl/plpython/expected/plpython_test.out b/src/pl/plpython/expected/plpython_test.out
index 847e4cc412..39b994f446 100644
--- a/src/pl/plpython/expected/plpython_test.out
+++ b/src/pl/plpython/expected/plpython_test.out
@@ -48,6 +48,7 @@ select module_contents();
  Error
  Fatal
  SPIError
+ commit
  cursor
  debug
  error
@@ -60,10 +61,11 @@ select module_contents();
  quote_ident
  quote_literal
  quote_nullable
+ rollback
  spiexceptions
  subtransaction
  warning
-(18 rows)
+(20 rows)
 
 CREATE FUNCTION elog_test_basic() RETURNS void
 AS $$
diff --git a/src/pl/plpython/expected/plpython_transaction.out b/src/pl/plpython/expected/plpython_transaction.out
new file mode 100644
index 0000000000..c5909fdb87
--- /dev/null
+++ b/src/pl/plpython/expected/plpython_transaction.out
@@ -0,0 +1,96 @@
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+DO
+LANGUAGE plpythonu
+$$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+return 1
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/Python function "transaction_test2"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("CALL transaction_test1()")
+return 1
+$$;
+SELECT transaction_test3();
+ERROR:  spiexceptions.InvalidTransactionTermination: invalid transaction termination
+CONTEXT:  Traceback (most recent call last):
+  PL/Python function "transaction_test3", line 2, in <module>
+    plpy.execute("CALL transaction_test1()")
+PL/Python function "transaction_test3"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$")
+return 1
+$$;
+SELECT transaction_test4();
+ERROR:  spiexceptions.InvalidTransactionTermination: invalid transaction termination
+CONTEXT:  Traceback (most recent call last):
+  PL/Python function "transaction_test4", line 2, in <module>
+    plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$")
+PL/Python function "transaction_test4"
+DROP TABLE test1;
diff --git a/src/pl/plpython/plpy_main.c b/src/pl/plpython/plpy_main.c
index 695de30583..254ab37359 100644
--- a/src/pl/plpython/plpy_main.c
+++ b/src/pl/plpython/plpy_main.c
@@ -262,6 +262,9 @@ plpython_call_handler(PG_FUNCTION_ARGS)
 		else
 		{
 			proc = PLy_procedure_get(funcoid, InvalidOid, false);
+			if (proc->is_procedure &&
+				!castNode(CallContext, fcinfo->context)->atomic)
+					SPI_set_nonatomic();
 			exec_ctx->curr_proc = proc;
 			retval = PLy_exec_function(fcinfo, proc);
 		}
@@ -305,6 +308,8 @@ plpython_inline_handler(PG_FUNCTION_ARGS)
 	/* Note: SPI_finish() happens in plpy_exec.c, which is dubious design */
 	if (SPI_connect() != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed");
+	if (!codeblock->atomic)
+		SPI_set_nonatomic();
 
 	MemSet(&fake_fcinfo, 0, sizeof(fake_fcinfo));
 	MemSet(&flinfo, 0, sizeof(flinfo));
@@ -435,7 +440,7 @@ PLy_push_execution_context(void)
 	PLyExecutionContext *context;
 
 	context = (PLyExecutionContext *)
-		MemoryContextAlloc(TopTransactionContext, sizeof(PLyExecutionContext));
+		MemoryContextAlloc(PortalContext, sizeof(PLyExecutionContext));
 	context->curr_proc = NULL;
 	context->scratch_ctx = NULL;
 	context->next = PLy_execution_contexts;
diff --git a/src/pl/plpython/plpy_plpymodule.c b/src/pl/plpython/plpy_plpymodule.c
index 23f99e20ca..b9b9e423a7 100644
--- a/src/pl/plpython/plpy_plpymodule.c
+++ b/src/pl/plpython/plpy_plpymodule.c
@@ -6,8 +6,10 @@
 
 #include "postgres.h"
 
+#include "access/xact.h"
 #include "mb/pg_wchar.h"
 #include "utils/builtins.h"
+#include "utils/snapmgr.h"
 
 #include "plpython.h"
 
@@ -41,6 +43,8 @@ static PyObject *PLy_fatal(PyObject *self, PyObject *args, PyObject *kw);
 static PyObject *PLy_quote_literal(PyObject *self, PyObject *args);
 static PyObject *PLy_quote_nullable(PyObject *self, PyObject *args);
 static PyObject *PLy_quote_ident(PyObject *self, PyObject *args);
+static PyObject *PLy_commit(PyObject *self, PyObject *args);
+static PyObject *PLy_rollback(PyObject *self, PyObject *args);
 
 
 /* A list of all known exceptions, generated from backend/utils/errcodes.txt */
@@ -95,6 +99,12 @@ static PyMethodDef PLy_methods[] = {
 	 */
 	{"cursor", PLy_cursor, METH_VARARGS, NULL},
 
+	/*
+	 * transaction control
+	 */
+	{"commit", PLy_commit, METH_NOARGS, NULL},
+	{"rollback", PLy_rollback, METH_NOARGS, NULL},
+
 	{NULL, NULL, 0, NULL}
 };
 
@@ -577,3 +587,21 @@ PLy_output(volatile int level, PyObject *self, PyObject *args, PyObject *kw)
 	 */
 	Py_RETURN_NONE;
 }
+
+static PyObject *
+PLy_commit(PyObject *self, PyObject *args)
+{
+	SPI_commit();
+	SPI_start_transaction();
+
+	Py_RETURN_NONE;
+}
+
+static PyObject *
+PLy_rollback(PyObject *self, PyObject *args)
+{
+	SPI_rollback();
+	SPI_start_transaction();
+
+	Py_RETURN_NONE;
+}
diff --git a/src/pl/plpython/sql/plpython_transaction.sql b/src/pl/plpython/sql/plpython_transaction.sql
new file mode 100644
index 0000000000..cbcc87f00b
--- /dev/null
+++ b/src/pl/plpython/sql/plpython_transaction.sql
@@ -0,0 +1,80 @@
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+DO
+LANGUAGE plpythonu
+$$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+return 1
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("CALL transaction_test1()")
+return 1
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$")
+return 1
+$$;
+
+SELECT transaction_test4();
+
+
+DROP TABLE test1;
diff --git a/src/pl/tcl/Makefile b/src/pl/tcl/Makefile
index 6a92a9b6aa..ef61ee596e 100644
--- a/src/pl/tcl/Makefile
+++ b/src/pl/tcl/Makefile
@@ -28,7 +28,7 @@ DATA = pltcl.control pltcl--1.0.sql pltcl--unpackaged--1.0.sql \
        pltclu.control pltclu--1.0.sql pltclu--unpackaged--1.0.sql
 
 REGRESS_OPTS = --dbname=$(PL_TESTDB) --load-extension=pltcl
-REGRESS = pltcl_setup pltcl_queries pltcl_call pltcl_start_proc pltcl_subxact pltcl_unicode
+REGRESS = pltcl_setup pltcl_queries pltcl_call pltcl_start_proc pltcl_subxact pltcl_unicode pltcl_transaction
 
 # Tcl on win32 ships with import libraries only for Microsoft Visual C++,
 # which are not compatible with mingw gcc. Therefore we need to build a
diff --git a/src/pl/tcl/expected/pltcl_transaction.out b/src/pl/tcl/expected/pltcl_transaction.out
new file mode 100644
index 0000000000..6ce900027c
--- /dev/null
+++ b/src/pl/tcl/expected/pltcl_transaction.out
@@ -0,0 +1,63 @@
+-- suppress CONTEXT so that function OIDs aren't in output
+\set VERBOSITY terse
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+return 1
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE pltcl
+AS $$
+spi_exec "CALL transaction_test1()"
+return 1
+$$;
+SELECT transaction_test3();
+ERROR:  invalid transaction termination
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+DROP TABLE test1;
diff --git a/src/pl/tcl/pltcl.c b/src/pl/tcl/pltcl.c
index e0792d93e1..0571755b4f 100644
--- a/src/pl/tcl/pltcl.c
+++ b/src/pl/tcl/pltcl.c
@@ -312,6 +312,10 @@ static int pltcl_SPI_lastoid(ClientData cdata, Tcl_Interp *interp,
 				  int objc, Tcl_Obj *const objv[]);
 static int pltcl_subtransaction(ClientData cdata, Tcl_Interp *interp,
 					 int objc, Tcl_Obj *const objv[]);
+static int pltcl_commit(ClientData cdata, Tcl_Interp *interp,
+					 int objc, Tcl_Obj *const objv[]);
+static int pltcl_rollback(ClientData cdata, Tcl_Interp *interp,
+					 int objc, Tcl_Obj *const objv[]);
 
 static void pltcl_subtrans_begin(MemoryContext oldcontext,
 					 ResourceOwner oldowner);
@@ -524,6 +528,10 @@ pltcl_init_interp(pltcl_interp_desc *interp_desc, Oid prolang, bool pltrusted)
 						 pltcl_SPI_lastoid, NULL, NULL);
 	Tcl_CreateObjCommand(interp, "subtransaction",
 						 pltcl_subtransaction, NULL, NULL);
+	Tcl_CreateObjCommand(interp, "commit",
+						 pltcl_commit, NULL, NULL);
+	Tcl_CreateObjCommand(interp, "rollback",
+						 pltcl_rollback, NULL, NULL);
 
 	/************************************************************
 	 * Call the appropriate start_proc, if there is one.
@@ -812,6 +820,10 @@ pltcl_func_handler(PG_FUNCTION_ARGS, pltcl_call_state *call_state,
 	prodesc = compile_pltcl_function(fcinfo->flinfo->fn_oid, InvalidOid,
 									 false, pltrusted);
 
+	if (prodesc->result_typid == InvalidOid &&
+		!castNode(CallContext, fcinfo->context)->atomic)
+		SPI_set_nonatomic();
+
 	call_state->prodesc = prodesc;
 	prodesc->fn_refcount++;
 
@@ -2935,6 +2947,38 @@ pltcl_subtransaction(ClientData cdata, Tcl_Interp *interp,
 }
 
 
+/**********************************************************************
+ * pltcl_commit()
+ *
+ * Commit the transaction and start a new one.
+ **********************************************************************/
+static int
+pltcl_commit(ClientData cdata, Tcl_Interp *interp,
+			 int objc, Tcl_Obj *const objv[])
+{
+	SPI_commit();
+	SPI_start_transaction();
+
+	return TCL_OK;
+}
+
+
+/**********************************************************************
+ * pltcl_rollback()
+ *
+ * Abort the transaction and start a new one.
+ **********************************************************************/
+static int
+pltcl_rollback(ClientData cdata, Tcl_Interp *interp,
+			   int objc, Tcl_Obj *const objv[])
+{
+	SPI_rollback();
+	SPI_start_transaction();
+
+	return TCL_OK;
+}
+
+
 /**********************************************************************
  * pltcl_set_tuple_values() - Set variables for all attributes
  *				  of a given tuple
diff --git a/src/pl/tcl/sql/pltcl_transaction.sql b/src/pl/tcl/sql/pltcl_transaction.sql
new file mode 100644
index 0000000000..14aed5844a
--- /dev/null
+++ b/src/pl/tcl/sql/pltcl_transaction.sql
@@ -0,0 +1,60 @@
+-- suppress CONTEXT so that function OIDs aren't in output
+\set VERBOSITY terse
+
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+return 1
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE pltcl
+AS $$
+spi_exec "CALL transaction_test1()"
+return 1
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+DROP TABLE test1;
diff --git a/src/test/regress/expected/plpgsql.out b/src/test/regress/expected/plpgsql.out
index d6e5bc3353..3fd5cb6180 100644
--- a/src/test/regress/expected/plpgsql.out
+++ b/src/test/regress/expected/plpgsql.out
@@ -6077,7 +6077,117 @@ SELECT * FROM proc_test1;
  55
 (1 row)
 
+TRUNCATE proc_test1;
+CREATE PROCEDURE test_proc_transaction1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+CALL test_proc_transaction1();
+SELECT * FROM proc_test1;
+ a 
+---
+ 0
+ 2
+ 4
+ 6
+ 8
+(5 rows)
+
+TRUNCATE proc_test1;
+DO
+LANGUAGE plpgsql
+$$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+SELECT * FROM proc_test1;
+ a 
+---
+ 0
+ 2
+ 4
+ 6
+ 8
+(5 rows)
+
+TRUNCATE proc_test1;
+-- not allowed in a function
+CREATE FUNCTION test_proc_transaction2() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+    RETURN 1;
+END
+$$;
+SELECT test_proc_transaction2();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function test_proc_transaction2() line 6 at COMMIT
+SELECT * FROM proc_test1;
+ a 
+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION test_proc_transaction3() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    CALL test_proc_transaction1();
+    RETURN 1;
+END;
+$$;
+SELECT test_proc_transaction3();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function test_proc_transaction1() line 6 at COMMIT
+SQL statement "CALL test_proc_transaction1()"
+PL/pgSQL function test_proc_transaction3() line 3 at SQL statement
+SELECT * FROM proc_test1;
+ a 
+---
+(0 rows)
+
+-- DO block inside function
+CREATE FUNCTION test_proc_transaction4() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    EXECUTE 'DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$';
+    RETURN 1;
+END;
+$$;
+SELECT test_proc_transaction4();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function inline_code_block line 1 at COMMIT
+SQL statement "DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$"
+PL/pgSQL function test_proc_transaction4() line 3 at EXECUTE
 DROP PROCEDURE test_proc1;
 DROP PROCEDURE test_proc2;
 DROP PROCEDURE test_proc3;
+DROP PROCEDURE test_proc_transaction1;
 DROP TABLE proc_test1;
diff --git a/src/test/regress/sql/plpgsql.sql b/src/test/regress/sql/plpgsql.sql
index 1c355132b7..4c1d5da436 100644
--- a/src/test/regress/sql/plpgsql.sql
+++ b/src/test/regress/sql/plpgsql.sql
@@ -4864,8 +4864,103 @@ CREATE PROCEDURE test_proc3(x int)
 SELECT * FROM proc_test1;
 
 
+TRUNCATE proc_test1;
+
+CREATE PROCEDURE test_proc_transaction1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+CALL test_proc_transaction1();
+
+SELECT * FROM proc_test1;
+
+
+TRUNCATE proc_test1;
+
+DO
+LANGUAGE plpgsql
+$$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+SELECT * FROM proc_test1;
+
+
+TRUNCATE proc_test1;
+
+-- not allowed in a function
+CREATE FUNCTION test_proc_transaction2() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+    RETURN 1;
+END
+$$;
+
+SELECT test_proc_transaction2();
+
+SELECT * FROM proc_test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION test_proc_transaction3() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    CALL test_proc_transaction1();
+    RETURN 1;
+END;
+$$;
+
+SELECT test_proc_transaction3();
+
+SELECT * FROM proc_test1;
+
+
+-- DO block inside function
+CREATE FUNCTION test_proc_transaction4() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    EXECUTE 'DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$';
+    RETURN 1;
+END;
+$$;
+
+SELECT test_proc_transaction4();
+
+
 DROP PROCEDURE test_proc1;
 DROP PROCEDURE test_proc2;
 DROP PROCEDURE test_proc3;
+DROP PROCEDURE test_proc_transaction1;
 
 DROP TABLE proc_test1;

base-commit: 87c37e3291cb75273ccdf4645b9472dd805c4493
-- 
2.15.0

#27Robert Haas
robertmhaas@gmail.com
In reply to: Peter Eisentraut (#26)
Re: [HACKERS] Transaction control in procedures

On Fri, Dec 1, 2017 at 2:48 PM, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

Here is a new patch, now on top of master. The main changes are that a
lot of documentation has been added.

This feature doesn't have many tests. I think it should have a lot
more of them. It's tinkering with the transaction control machinery
of the system in a fairly fundamental way, and that could break
things.

I suggest, in particular, testing how it interactions with resources
such as cursors and prepared statements. For example, what happens if
you commit or roll back inside a cursor-for loop (given that the
cursor is not holdable)? There are several kinds of cursor loops in
PostgreSQL, plus there are cursors, prepared statements, and portals
that can be created using SQL commands or protocol messages. I
suspect that there are quite a few tricky interactions there.

Other things to think about:

- COMMIT or ROLLBACK inside a PLpgsql block with an attached EXCEPTION
block, or when an SQL SAVEPOINT has been established previously.

- COMMIT or ROLLBACK inside a procedure with a SET clause attached,
and/or while SET LOCAL is in effect either at the inner or outer
level.

- COMMIT or ROLLBACK with open large objects.

- COMMIT inside a procedure fails because of a serialization failure,
deferred constraint, etc.

In some cases, there are not only questions of correctness (it
shouldn't crash/give wrong answers) but also definitional questions
(what exactly should happen in that case, anyway?).

--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company

#28Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: Robert Haas (#27)
Re: [HACKERS] Transaction control in procedures

On 12/1/17 15:28, Robert Haas wrote:

This feature doesn't have many tests. I think it should have a lot
more of them. It's tinkering with the transaction control machinery
of the system in a fairly fundamental way, and that could break
things.

Thank you, these are great ideas.

I suggest, in particular, testing how it interactions with resources
such as cursors and prepared statements. For example, what happens if
you commit or roll back inside a cursor-for loop (given that the
cursor is not holdable)?

This was discussed briefly earlier in the thread. The mid-term fix is
to convert pinned cursors to holdable ones before a COMMIT in PL/pgSQL
and then clean them up separately later. I have that mostly working,
but I'd like to hold it for a separate patch submission. The short-term
fix is to prohibit COMMIT and ROLLBACK while a portal is pinned.

I think ROLLBACK in a cursor loop might not make sense, because the
cursor query itself could have side effects, so a rollback would have to
roll back the entire loop. That might need more refined analysis before
it could be allowed.

- COMMIT or ROLLBACK inside a PLpgsql block with an attached EXCEPTION
block, or when an SQL SAVEPOINT has been established previously.

I think that needs to be prohibited because if you end transactions in
an exception-handled block, you can no longer actually roll back that
block when an exception occurs, which was the entire point.

- COMMIT or ROLLBACK inside a procedure with a SET clause attached,

That also needs to be prohibited because of the way the GUC nesting
currently works. It's probably possible to fix it, but it would be a
separate effort.

and/or while SET LOCAL is in effect either at the inner or outer
level.

That seems to work fine.

- COMMIT or ROLLBACK with open large objects.

I haven't been able to reproduce any problems with that, but maybe I
haven't tried hard enough.

- COMMIT inside a procedure fails because of a serialization failure,
deferred constraint, etc.

That works fine. The COMMIT fails and control exits the procedure using
the normal exception propagation.

I'll submit an updated patch with some fixes for the above and more
documentation.

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#29Robert Haas
robertmhaas@gmail.com
In reply to: Peter Eisentraut (#28)
Re: [HACKERS] Transaction control in procedures

On Tue, Dec 5, 2017 at 1:25 PM, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

I think ROLLBACK in a cursor loop might not make sense, because the
cursor query itself could have side effects, so a rollback would have to
roll back the entire loop. That might need more refined analysis before
it could be allowed.

COMMIT really has the same problem; if the cursor query has side
effects, you can't commit those side effects piecemeal as the loop
executed and have things behave sanely.

- COMMIT or ROLLBACK inside a procedure with a SET clause attached,

That also needs to be prohibited because of the way the GUC nesting
currently works. It's probably possible to fix it, but it would be a
separate effort.

and/or while SET LOCAL is in effect either at the inner or outer
level.

That seems to work fine.

These two are related -- if you don't permit anything that makes
temporary changes to GUCs at all, like SET clauses attached to
functions, then SET LOCAL won't cause any problems. The problem is if
you do a transaction operation when something set locally is in the
stack of values, but not at the top.

--
Robert Haas
EnterpriseDB: http://www.enterprisedb.com
The Enterprise PostgreSQL Company

#30Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: Robert Haas (#29)
1 attachment(s)
Re: [HACKERS] Transaction control in procedures

On 12/5/17 13:33, Robert Haas wrote:

On Tue, Dec 5, 2017 at 1:25 PM, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

I think ROLLBACK in a cursor loop might not make sense, because the
cursor query itself could have side effects, so a rollback would have to
roll back the entire loop. That might need more refined analysis before
it could be allowed.

COMMIT really has the same problem; if the cursor query has side
effects, you can't commit those side effects piecemeal as the loop
executed and have things behave sanely.

The first COMMIT inside the loop would commit the cursor query. This
isn't all that different from what you'd get now if you coded this
manually using holdable cursors or just plain client code. Clearly, you
can create a mess if the loop body interacts with the loop expression,
but that's already the case.

But if you coded something like this yourself now and ran a ROLLBACK
inside the loop, the holdable cursor would disappear (unless previously
committed), so you couldn't proceed with the loop.

The SQL standard for persistent stored modules explicitly prohibits
COMMIT and ROLLBACK in cursor loop bodies. But I think people will
eventually want it.

- COMMIT or ROLLBACK inside a procedure with a SET clause attached,

That also needs to be prohibited because of the way the GUC nesting
currently works. It's probably possible to fix it, but it would be a
separate effort.

and/or while SET LOCAL is in effect either at the inner or outer
level.

That seems to work fine.

These two are related -- if you don't permit anything that makes
temporary changes to GUCs at all, like SET clauses attached to
functions, then SET LOCAL won't cause any problems. The problem is if
you do a transaction operation when something set locally is in the
stack of values, but not at the top.

Yes, that's exactly the problem. So right now I'm just preventing the
problematic scenario. So fix that, one would possibly have to replace
the stack by something not quite a stack.

New patch attached.

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

Attachments:

v4-0001-Transaction-control-in-PL-procedures.patchtext/plain; charset=UTF-8; name=v4-0001-Transaction-control-in-PL-procedures.patch; x-mac-creator=0; x-mac-type=0Download
From 18aaf292fbb22647e09c38cc21b56ff98643e518 Mon Sep 17 00:00:00 2001
From: Peter Eisentraut <peter_e@gmx.net>
Date: Wed, 6 Dec 2017 09:29:25 -0500
Subject: [PATCH v4] Transaction control in PL procedures

In each of the supplied procedural languages (PL/pgSQL, PL/Perl,
PL/Python, PL/Tcl), add language-specific commit and rollback
functions/commands to control transactions in procedures in that
language.  Add similar underlying functions to SPI.  Some additional
cleanup so that transaction commit or abort doesn't blow away data
structures still used by the procedure call.  Add execution context
tracking to CALL and DO statements so that transaction control commands
can only be issued in top-level procedure and block calls, not function
calls or other procedure or block calls.
---
 doc/src/sgml/plperl.sgml                          |  49 +++++
 doc/src/sgml/plpgsql.sgml                         |  91 ++++----
 doc/src/sgml/plpython.sgml                        |  38 ++++
 doc/src/sgml/pltcl.sgml                           |  41 ++++
 doc/src/sgml/ref/call.sgml                        |   7 +
 doc/src/sgml/ref/create_procedure.sgml            |   7 +
 doc/src/sgml/ref/do.sgml                          |   7 +
 doc/src/sgml/spi.sgml                             | 219 ++++++++++++++++++++
 src/backend/commands/functioncmds.c               |  45 +++-
 src/backend/executor/spi.c                        | 112 ++++++++--
 src/backend/tcop/utility.c                        |   6 +-
 src/backend/utils/mmgr/portalmem.c                |  58 +++---
 src/include/commands/defrem.h                     |   4 +-
 src/include/executor/spi.h                        |   5 +
 src/include/executor/spi_priv.h                   |   4 +
 src/include/nodes/nodes.h                         |   3 +-
 src/include/nodes/parsenodes.h                    |   7 +
 src/include/utils/portal.h                        |   1 +
 src/pl/plperl/GNUmakefile                         |   2 +-
 src/pl/plperl/SPI.xs                              |  12 ++
 src/pl/plperl/expected/plperl_transaction.out     |  94 +++++++++
 src/pl/plperl/plperl.c                            |   6 +
 src/pl/plperl/sql/plperl_transaction.sql          |  88 ++++++++
 src/pl/plpgsql/src/pl_exec.c                      |  66 +++++-
 src/pl/plpgsql/src/pl_funcs.c                     |  44 ++++
 src/pl/plpgsql/src/pl_gram.y                      |  34 +++
 src/pl/plpgsql/src/pl_handler.c                   |   8 +
 src/pl/plpgsql/src/pl_scanner.c                   |   2 +
 src/pl/plpgsql/src/plpgsql.h                      |  22 +-
 src/pl/plpython/Makefile                          |   1 +
 src/pl/plpython/expected/plpython_test.out        |   4 +-
 src/pl/plpython/expected/plpython_transaction.out | 104 ++++++++++
 src/pl/plpython/plpy_main.c                       |   7 +-
 src/pl/plpython/plpy_plpymodule.c                 |  28 +++
 src/pl/plpython/sql/plpython_transaction.sql      |  87 ++++++++
 src/pl/tcl/Makefile                               |   2 +-
 src/pl/tcl/expected/pltcl_transaction.out         |  63 ++++++
 src/pl/tcl/pltcl.c                                |  44 ++++
 src/pl/tcl/sql/pltcl_transaction.sql              |  60 ++++++
 src/test/regress/expected/plpgsql.out             | 241 ++++++++++++++++++++++
 src/test/regress/sql/plpgsql.sql                  | 214 +++++++++++++++++++
 41 files changed, 1835 insertions(+), 102 deletions(-)
 create mode 100644 src/pl/plperl/expected/plperl_transaction.out
 create mode 100644 src/pl/plperl/sql/plperl_transaction.sql
 create mode 100644 src/pl/plpython/expected/plpython_transaction.out
 create mode 100644 src/pl/plpython/sql/plpython_transaction.sql
 create mode 100644 src/pl/tcl/expected/pltcl_transaction.out
 create mode 100644 src/pl/tcl/sql/pltcl_transaction.sql

diff --git a/doc/src/sgml/plperl.sgml b/doc/src/sgml/plperl.sgml
index 100162dead..82ddf26606 100644
--- a/doc/src/sgml/plperl.sgml
+++ b/doc/src/sgml/plperl.sgml
@@ -661,6 +661,55 @@ <title>Database Access from PL/Perl</title>
     </para>
     </listitem>
     </varlistentry>
+
+    <varlistentry>
+     <term>
+      <literal><function>spi_commit()</function></literal>
+      <indexterm>
+       <primary>spi_commit</primary>
+       <secondary>in PL/Perl</secondary>
+     </indexterm>
+     </term>
+     <term>
+      <literal><function>spi_rollback()</function></literal>
+      <indexterm>
+       <primary>spi_rollback</primary>
+       <secondary>in PL/Perl</secondary>
+      </indexterm>
+     </term>
+     <listitem>
+      <para>
+       Commit or roll back the current transaction.  This can only be called
+       in a procedure or anonymous code block called from the top level.
+       (Note that it is not possible to run the SQL
+       commands <command>COMMIT</command> or <command>ROLLBACK</command>
+       via <function>spi_exec_query</function> or similar.  It has to be done
+       using these functions.)  After a transaction is ended, a new
+       transaction is automatically started, so there is no separate function
+       for that.
+      </para>
+
+      <para>
+       Here is an example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+CALL transaction_test1();
+</programlisting>
+      </para>
+     </listitem>
+    </varlistentry>
    </variablelist>
  </sect2>
 
diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml
index 7d23ed437e..285467343a 100644
--- a/doc/src/sgml/plpgsql.sgml
+++ b/doc/src/sgml/plpgsql.sgml
@@ -3449,6 +3449,48 @@ <title>Looping Through a Cursor's Result</title>
 
   </sect1>
 
+  <sect1 id="plpgsql-transactions">
+   <title>Transaction Management</title>
+
+   <para>
+    In procedures invoked by the <command>CALL</command> command from the top
+    level as well as in anonymous code blocks called from the top level, it is
+    possible to end transactions using the commands <command>COMMIT</command>
+    and <command>ROLLBACK</command>.  A new transaction is started
+    automatically after a transaction is ended using these commands, so there
+    is no separate <command>START TRANSACTION</command> command.  (And of
+    course, <command>BEGIN</command> and <command>END</command> have different
+    meanings in PL/pgSQL.)
+   </para>
+
+   <para>
+    Here is a simple example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+CALL transaction_test1();
+</programlisting>
+   </para>
+
+   <para>
+    Transactions cannot be ended inside loops through query results or inside
+    blocks with exception handlers.
+   </para>
+  </sect1>
+
   <sect1 id="plpgsql-errors-and-messages">
    <title>Errors and Messages</title>
 
@@ -5432,14 +5474,13 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
 <programlisting>
 CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id IN INTEGER) IS
     a_running_job_count INTEGER;
-    PRAGMA AUTONOMOUS_TRANSACTION; -- <co id="co.plpgsql-porting-pragma"/>
 BEGIN
-    LOCK TABLE cs_jobs IN EXCLUSIVE MODE; -- <co id="co.plpgsql-porting-locktable"/>
+    LOCK TABLE cs_jobs IN EXCLUSIVE MODE;
 
     SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL;
 
     IF a_running_job_count &gt; 0 THEN
-        COMMIT; -- free lock <co id="co.plpgsql-porting-commit"/>
+        COMMIT; -- free lock
         raise_application_error(-20000,
                  'Unable to create a new job: a job is currently running.');
     END IF;
@@ -5459,45 +5500,11 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
 </programlisting>
    </para>
 
-   <para>
-    Procedures like this can easily be converted into <productname>PostgreSQL</productname>
-    functions returning <type>void</type>. This procedure in
-    particular is interesting because it can teach us some things:
-
-    <calloutlist>
-     <callout arearefs="co.plpgsql-porting-pragma">
-      <para>
-       There is no <literal>PRAGMA</literal> statement in <productname>PostgreSQL</productname>.
-      </para>
-     </callout>
-
-     <callout arearefs="co.plpgsql-porting-locktable">
-      <para>
-       If you do a <command>LOCK TABLE</command> in <application>PL/pgSQL</application>,
-       the lock will not be released until the calling transaction is
-       finished.
-      </para>
-     </callout>
-
-     <callout arearefs="co.plpgsql-porting-commit">
-      <para>
-       You cannot issue <command>COMMIT</command> in a
-       <application>PL/pgSQL</application> function.  The function is
-       running within some outer transaction and so <command>COMMIT</command>
-       would imply terminating the function's execution.  However, in
-       this particular case it is not necessary anyway, because the lock
-       obtained by the <command>LOCK TABLE</command> will be released when
-       we raise an error.
-      </para>
-     </callout>
-    </calloutlist>
-   </para>
-
    <para>
     This is how we could port this procedure to <application>PL/pgSQL</application>:
 
 <programlisting>
-CREATE OR REPLACE FUNCTION cs_create_job(v_job_id integer) RETURNS void AS $$
+CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id integer) AS $$
 DECLARE
     a_running_job_count integer;
 BEGIN
@@ -5506,6 +5513,7 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
     SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL;
 
     IF a_running_job_count &gt; 0 THEN
+        COMMIT; -- free lock
         RAISE EXCEPTION 'Unable to create a new job: a job is currently running'; -- <co id="co.plpgsql-porting-raise"/>
     END IF;
 
@@ -5518,6 +5526,7 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
         WHEN unique_violation THEN -- <co id="co.plpgsql-porting-exception"/>
             -- don't worry if it already exists
     END;
+    COMMIT;
 END;
 $$ LANGUAGE plpgsql;
 </programlisting>
@@ -5541,12 +5550,6 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
       </para>
      </callout>
     </calloutlist>
-
-    The main functional difference between this procedure and the
-    Oracle equivalent is that the exclusive lock on the <literal>cs_jobs</literal>
-    table will be held until the calling transaction completes.  Also, if
-    the caller later aborts (for example due to an error), the effects of
-    this procedure will be rolled back.
    </para>
    </example>
   </sect2>
diff --git a/doc/src/sgml/plpython.sgml b/doc/src/sgml/plpython.sgml
index 0dbeee1fa2..76cc0fc314 100644
--- a/doc/src/sgml/plpython.sgml
+++ b/doc/src/sgml/plpython.sgml
@@ -1370,6 +1370,44 @@ <title>Older Python Versions</title>
   </sect2>
  </sect1>
 
+ <sect1 id="plpython-transactions">
+  <title>Transaction Management</title>
+
+  <para>
+   In a procedure called from the top level or an anonymous code block called
+   from the top level it is possible to control transactions.  To commit the
+   current transaction, call <literal>plpy.commit()</literal>.  To roll back
+   the current transaction, call <literal>plpy.rollback()</literal>.  (Note
+   that it is not possible to run the SQL commands <command>COMMIT</command>
+   or <command>ROLLBACK</command> via <function>plpy.execute</function> or
+   similar.  It has to be done using these functions.)  After a transaction is
+   ended, a new transaction is automatically started, so there is no separate
+   function for that.
+  </para>
+
+  <para>
+   Here is an example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+CALL transaction_test1();
+</programlisting>
+  </para>
+
+  <para>
+   Transactions cannot be ended when an explicit subtransaction is active.
+  </para>
+ </sect1>
+
  <sect1 id="plpython-util">
   <title>Utility Functions</title>
   <para>
diff --git a/doc/src/sgml/pltcl.sgml b/doc/src/sgml/pltcl.sgml
index 8018783b0a..f7604d4787 100644
--- a/doc/src/sgml/pltcl.sgml
+++ b/doc/src/sgml/pltcl.sgml
@@ -1002,6 +1002,47 @@ <title>Explicit Subtransactions in PL/Tcl</title>
     </para>
    </sect1>
 
+   <sect1 id="pltcl-transactions">
+    <title>Transaction Management</title>
+
+    <para>
+     In a procedure called from the top level or an anonymous code block
+     called from the top level it is possible to control transactions.  To
+     commit the current transaction, call the <literal>commit</literal>
+     command.  To roll back the current transaction, call
+     the <literal>rollback</literal> command.  (Note that it is not possible
+     to run the SQL commands <command>COMMIT</command>
+     or <command>ROLLBACK</command> via <function>spi_exec</function> or
+     similar.  It has to be done using these functions.)  After a transaction
+     is ended, a new transaction is automatically started, so there is no
+     separate command for that.
+    </para>
+
+    <para>
+     Here is an example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i &lt; 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+
+CALL transaction_test1();
+</programlisting>
+    </para>
+
+    <para>
+     Transactions cannot be ended when an explicit subtransaction is active.
+    </para>
+   </sect1>
+
    <sect1 id="pltcl-config">
     <title>PL/Tcl Configuration</title>
 
diff --git a/doc/src/sgml/ref/call.sgml b/doc/src/sgml/ref/call.sgml
index 2741d8d15e..03da4518ee 100644
--- a/doc/src/sgml/ref/call.sgml
+++ b/doc/src/sgml/ref/call.sgml
@@ -70,6 +70,13 @@ <title>Notes</title>
   <para>
    To call a function (not a procedure), use <command>SELECT</command> instead.
   </para>
+
+  <para>
+   If <command>CALL</command> is executed in a transaction block, then the
+   called procedure cannot execute transaction control statements.
+   Transaction control statements are only allowed if <command>CALL</command>
+   is executed in its own transaction.
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_procedure.sgml b/doc/src/sgml/ref/create_procedure.sgml
index d712043824..bbf8b03d04 100644
--- a/doc/src/sgml/ref/create_procedure.sgml
+++ b/doc/src/sgml/ref/create_procedure.sgml
@@ -228,6 +228,13 @@ <title>Parameters</title>
        procedure exit, unless the current transaction is rolled back.
       </para>
 
+      <para>
+       If a <literal>SET</literal> clause is attached to a procedure, then
+       that procedure cannot execute transaction control statements (for
+       example, <command>COMMIT</command> and <command>ROLLBACK</command>,
+       depending on the language).
+      </para>
+
       <para>
        See <xref linkend="sql-set"/> and
        <xref linkend="runtime-config"/>
diff --git a/doc/src/sgml/ref/do.sgml b/doc/src/sgml/ref/do.sgml
index 061218b135..b9a6f9a6fd 100644
--- a/doc/src/sgml/ref/do.sgml
+++ b/doc/src/sgml/ref/do.sgml
@@ -91,6 +91,13 @@ <title>Notes</title>
    This is the same privilege requirement as for creating a function
    in the language.
   </para>
+
+  <para>
+   If <command>DO</command> is executed in a transaction block, then the
+   procedure code cannot execute transaction control statements.  Transaction
+   control statements are only allowed if <command>DO</command> is executed in
+   its own transaction.
+  </para>
  </refsect1>
 
  <refsect1 id="sql-do-examples">
diff --git a/doc/src/sgml/spi.sgml b/doc/src/sgml/spi.sgml
index 350f0863e9..6df8f8368b 100644
--- a/doc/src/sgml/spi.sgml
+++ b/doc/src/sgml/spi.sgml
@@ -4325,6 +4325,225 @@ <title>Return Value</title>
 
  </sect1>
 
+ <sect1 id="spi-transaction">
+  <title>Transaction Management</title>
+
+  <para>
+   It is not possible to run transaction control commands such
+   as <command>COMMIT</command> and <command>ROLLBACK</command> through SPI
+   functions such as <function>SPI_execute</function>.  There are, however,
+   separate interface functions that allow transaction control through SPI.
+  </para>
+
+  <para>
+   It is not generally safe and sensible to start and end transactions in
+   arbitrary user-defined SQL-callable functions without taking into account
+   the context in which they are called.  For example, a transaction boundary
+   in the middle of a function that is part of a complex SQL expression that
+   is part of some SQL command will probably result in obscure internal errors
+   or crashes.  The interface functions presented here are primarily intended
+   to be used by procedural language implementations to support transaction
+   management in procedures that are invoked by the <command>CALL</command>
+   command, taking the context of the <command>CALL</command> invocation into
+   account.  SPI procedures implemented in C can implement the same logic, but
+   the details of that are beyond the scope of this documentation.
+  </para>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-commit">
+ <indexterm><primary>SPI_commit</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_commit</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_commit</refname>
+  <refpurpose>commit the current transaction</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+int SPI_commit(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_commit</function> commits the current transaction.  It is
+   approximately equivalent to running the SQL
+   command <command>COMMIT</command>.  After a transaction is committed, a new
+   transaction has to be started
+   using <function>SPI_start_transaction</function> before further database
+   actions can be executed.
+  </para>
+
+  <para>
+   Before this function can be
+   executed, <function>SPI_set_nonatomic</function> has to be called for the
+   current SPI connection.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>Return Value</title>
+
+  <para>
+   0 on success
+  </para>
+ </refsect1>
+</refentry>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-rollback">
+ <indexterm><primary>SPI_rollback</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_rollback</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_rollback</refname>
+  <refpurpose>abort the current transaction</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+int SPI_rollback(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_rollback</function> rolls back the current transaction.  It
+   is approximately equivalent to running the SQL
+   command <command>ROLLBACK</command>.  After a transaction is rolled back, a
+   new transaction has to be started
+   using <function>SPI_start_transaction</function> before further database
+   actions can be executed.
+  </para>
+
+  <para>
+   Before this function can be
+   executed, <function>SPI_set_nonatomic</function> has to be called for the
+   current SPI connection.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>Return Value</title>
+
+  <para>
+   0 on success
+  </para>
+ </refsect1>
+</refentry>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-set-nonatomic">
+ <indexterm><primary>SPI_set_nonatomic</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_set_nonatomic</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_set_nonatomic</refname>
+  <refpurpose>makes current SPI connection nonatomic</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+int SPI_set_nonatomic(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_set_nonatomic</function> sets the current SPI connection to
+   be <firstterm>nonatomic</firstterm>, which means that transaction control
+   calls <function>SPI_commit</function>, <function>SPI_rollback</function>,
+   and <function>SPI_start_transaction</function> are allowed.  Otherwise,
+   calling these functions will result in an immediate
+   error.  <function>SPI_set_nonatomic</function> has to be called
+   after <function>SPI_connect</function> and its effects are canceled by the
+   corresponding <function>SPI_finish</function>, but it can be called at any
+   point in between.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>Return Value</title>
+
+  <para>
+   0 on success
+  </para>
+ </refsect1>
+</refentry>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-start-transaction">
+ <indexterm><primary>SPI_start_transaction</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_start_transaction</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_start_transaction</refname>
+  <refpurpose>start a new transaction</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+int SPI_start_transaction(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_start_transaction</function> starts a new transaction.  It
+   can only be called after <function>SPI_commit</function>
+   or <function>SPI_rollback</function>, as there is no transaction active at
+   that point.  Normally, when an SPI procedure is called, there is already a
+   transaction active, so attempting to start another one before closing out
+   the current one will result in an error.
+  </para>
+
+  <para>
+   Before this function can be
+   executed, <function>SPI_set_nonatomic</function> has to be called for the
+   current SPI connection.
+  </para>
+ </refsect1>
+
+ <refsect1>
+  <title>Return Value</title>
+
+  <para>
+   0 on success
+  </para>
+ </refsect1>
+</refentry>
+
+ </sect1>
+
  <sect1 id="spi-visibility">
   <title>Visibility of Data Changes</title>
 
diff --git a/src/backend/commands/functioncmds.c b/src/backend/commands/functioncmds.c
index 2a9c90133d..4101817c5e 100644
--- a/src/backend/commands/functioncmds.c
+++ b/src/backend/commands/functioncmds.c
@@ -65,6 +65,7 @@
 #include "utils/fmgroids.h"
 #include "utils/guc.h"
 #include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/rel.h"
 #include "utils/syscache.h"
 #include "utils/tqual.h"
@@ -2138,7 +2139,7 @@ IsThereFunctionInNamespace(const char *proname, int pronargs,
  *		Execute inline procedural-language code
  */
 void
-ExecuteDoStmt(DoStmt *stmt)
+ExecuteDoStmt(DoStmt *stmt, bool atomic)
 {
 	InlineCodeBlock *codeblock = makeNode(InlineCodeBlock);
 	ListCell   *arg;
@@ -2200,6 +2201,7 @@ ExecuteDoStmt(DoStmt *stmt)
 	codeblock->langOid = HeapTupleGetOid(languageTuple);
 	languageStruct = (Form_pg_language) GETSTRUCT(languageTuple);
 	codeblock->langIsTrusted = languageStruct->lanpltrusted;
+	codeblock->atomic = atomic;
 
 	if (languageStruct->lanpltrusted)
 	{
@@ -2236,9 +2238,28 @@ ExecuteDoStmt(DoStmt *stmt)
 
 /*
  * Execute CALL statement
+ *
+ * Inside a top-level CALL statement, transaction-terminating commands such as
+ * COMMIT or a PL-specific equivalent are allowed.  The terminology in the SQL
+ * standard is that CALL establishes a non-atomic execution context.  Most
+ * other commands establish an atomic execution context, in which transaction
+ * control actions are not allowed.  If there are nested executions of CALL,
+ * we want to track the execution context recursively, so that the nested
+ * CALLs can also do transaction control.  Note, however, that for example in
+ * CALL -> SELECT -> CALL, the second call cannot do transaction control,
+ * because the SELECT in between establishes an atomic execution context.
+ *
+ * So when ExecuteCallStmt() is called from the top level, we pass in atomic =
+ * false (recall that that means transactions = yes).  We then create a
+ * CallContext node with content atomic = false, which is passed in the
+ * fcinfo->context field to the procedure invocation.  The language
+ * implementation should then take appropriate measures to allow or prevent
+ * transaction commands based on that information, e.g., call
+ * SPI_set_nonatomic().  The language should also pass on the atomic flag to
+ * any recursive invocations to CALL.
  */
 void
-ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
+ExecuteCallStmt(ParseState *pstate, CallStmt *stmt, bool atomic)
 {
 	List	   *targs;
 	ListCell   *lc;
@@ -2249,6 +2270,8 @@ ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
 	AclResult   aclresult;
 	FmgrInfo	flinfo;
 	FunctionCallInfoData fcinfo;
+	CallContext *callcontext;
+	HeapTuple	tp;
 
 	targs = NIL;
 	foreach(lc, stmt->funccall->args)
@@ -2284,8 +2307,24 @@ ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
 							   FUNC_MAX_ARGS,
 							   FUNC_MAX_ARGS)));
 
+	callcontext = makeNode(CallContext);
+	callcontext->atomic = atomic;
+
+	/*
+	 * If proconfig is set we can't allow transaction commands because of the
+	 * way the GUC stacking works: The transaction boundary would have to pop
+	 * the proconfig setting off the stack.  That restriction could be lifted
+	 * by redesigning the GUC nesting mechanism a bit.
+	 */
+	tp = SearchSysCache1(PROCOID, ObjectIdGetDatum(fexpr->funcid));
+	if (!HeapTupleIsValid(tp))
+		elog(ERROR, "cache lookup failed for function %u", fexpr->funcid);
+	if (!heap_attisnull(tp, Anum_pg_proc_proconfig))
+		callcontext->atomic = true;
+	ReleaseSysCache(tp);
+
 	fmgr_info(fexpr->funcid, &flinfo);
-	InitFunctionCallInfoData(fcinfo, &flinfo, nargs, fexpr->inputcollid, NULL, NULL);
+	InitFunctionCallInfoData(fcinfo, &flinfo, nargs, fexpr->inputcollid, (Node *) callcontext, NULL);
 
 	i = 0;
 	foreach (lc, fexpr->args)
diff --git a/src/backend/executor/spi.c b/src/backend/executor/spi.c
index 2da1cac3e2..57c689c60b 100644
--- a/src/backend/executor/spi.c
+++ b/src/backend/executor/spi.c
@@ -92,7 +92,7 @@ SPI_connect(void)
 			elog(ERROR, "SPI stack corrupted");
 		newdepth = 16;
 		_SPI_stack = (_SPI_connection *)
-			MemoryContextAlloc(TopTransactionContext,
+			MemoryContextAlloc(TopMemoryContext,
 							   newdepth * sizeof(_SPI_connection));
 		_SPI_stack_depth = newdepth;
 	}
@@ -124,6 +124,7 @@ SPI_connect(void)
 	_SPI_current->execCxt = NULL;
 	_SPI_current->connectSubid = GetCurrentSubTransactionId();
 	_SPI_current->queryEnv = NULL;
+	_SPI_current->atomic = true;	/* until told otherwise */
 
 	/*
 	 * Create memory contexts for this procedure
@@ -133,10 +134,10 @@ SPI_connect(void)
 	 * Perhaps CurTransactionContext would do?	For now it doesn't matter
 	 * because we clean up explicitly in AtEOSubXact_SPI().
 	 */
-	_SPI_current->procCxt = AllocSetContextCreate(TopTransactionContext,
+	_SPI_current->procCxt = AllocSetContextCreate(PortalContext,
 												  "SPI Proc",
 												  ALLOCSET_DEFAULT_SIZES);
-	_SPI_current->execCxt = AllocSetContextCreate(TopTransactionContext,
+	_SPI_current->execCxt = AllocSetContextCreate(_SPI_current->procCxt,
 												  "SPI Exec",
 												  ALLOCSET_DEFAULT_SIZES);
 	/* ... and switch to procedure's context */
@@ -145,6 +146,17 @@ SPI_connect(void)
 	return SPI_OK_CONNECT;
 }
 
+int
+SPI_set_nonatomic(void)
+{
+	if (_SPI_current == NULL)
+		return SPI_ERROR_UNCONNECTED;
+
+	_SPI_current->atomic = false;
+
+	return SPI_OK_CONNECT;
+}
+
 int
 SPI_finish(void)
 {
@@ -158,8 +170,6 @@ SPI_finish(void)
 	MemoryContextSwitchTo(_SPI_current->savedcxt);
 
 	/* Release memory used in procedure call (including tuptables) */
-	MemoryContextDelete(_SPI_current->execCxt);
-	_SPI_current->execCxt = NULL;
 	MemoryContextDelete(_SPI_current->procCxt);
 	_SPI_current->procCxt = NULL;
 
@@ -181,12 +191,87 @@ SPI_finish(void)
 	return SPI_OK_FINISH;
 }
 
+int
+SPI_start_transaction(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	StartTransactionCommand();
+	MemoryContextSwitchTo(oldcontext);
+	return 0;
+}
+
+int
+SPI_commit(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	if (_SPI_current->atomic)
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("invalid transaction termination")));
+
+	/*
+	 * This restriction is particular to PLs implemented on top of SPI.  They
+	 * use subtransactions to establish exception blocks that are supposed to
+	 * be rolled back together if there is an error.  Terminating the
+	 * top-level transaction in such a block violates that idea.  A future PL
+	 * implementation might have different ideas about this, in which case
+	 * this restriction would have to be refined or the check possibly be
+	 * moved out of SPI into the PLs.
+	 */
+	if (IsSubTransaction())
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("cannot commit while a subtransaction is active")));
+
+	_SPI_current->internal_xact = true;
+
+	if (ActiveSnapshotSet())
+		PopActiveSnapshot();
+	CommitTransactionCommand();
+	MemoryContextSwitchTo(oldcontext);
+
+	_SPI_current->internal_xact = false;
+
+	return 0;
+}
+
+int
+SPI_rollback(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	if (_SPI_current->atomic)
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("invalid transaction termination")));
+
+	/* see under SPI_commit() */
+	if (IsSubTransaction())
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("cannot roll back while a subtransaction is active")));
+
+	_SPI_current->internal_xact = true;
+
+	AbortCurrentTransaction();
+	MemoryContextSwitchTo(oldcontext);
+
+	_SPI_current->internal_xact = false;
+
+	return 0;
+}
+
 /*
  * Clean up SPI state at transaction commit or abort.
  */
 void
 AtEOXact_SPI(bool isCommit)
 {
+	if (_SPI_current && _SPI_current->internal_xact)
+		return;
+
 	/*
 	 * Note that memory contexts belonging to SPI stack entries will be freed
 	 * automatically, so we can ignore them here.  We just need to restore our
@@ -224,21 +309,10 @@ AtEOSubXact_SPI(bool isCommit, SubTransactionId mySubid)
 		if (connection->connectSubid != mySubid)
 			break;				/* couldn't be any underneath it either */
 
-		found = true;
+		if (connection->internal_xact)
+			break;
 
-		/*
-		 * Release procedure memory explicitly (see note in SPI_connect)
-		 */
-		if (connection->execCxt)
-		{
-			MemoryContextDelete(connection->execCxt);
-			connection->execCxt = NULL;
-		}
-		if (connection->procCxt)
-		{
-			MemoryContextDelete(connection->procCxt);
-			connection->procCxt = NULL;
-		}
+		found = true;
 
 		/*
 		 * Pop the stack entry and reset global variables.  Unlike
diff --git a/src/backend/tcop/utility.c b/src/backend/tcop/utility.c
index 4da1f8f643..35f018c8da 100644
--- a/src/backend/tcop/utility.c
+++ b/src/backend/tcop/utility.c
@@ -529,7 +529,8 @@ standard_ProcessUtility(PlannedStmt *pstmt,
 			break;
 
 		case T_DoStmt:
-			ExecuteDoStmt((DoStmt *) parsetree);
+			ExecuteDoStmt((DoStmt *) parsetree,
+						  (context != PROCESS_UTILITY_TOPLEVEL || IsTransactionBlock()));
 			break;
 
 		case T_CreateTableSpaceStmt:
@@ -658,7 +659,8 @@ standard_ProcessUtility(PlannedStmt *pstmt,
 			break;
 
 		case T_CallStmt:
-			ExecuteCallStmt(pstate, castNode(CallStmt, parsetree));
+			ExecuteCallStmt(pstate, castNode(CallStmt, parsetree),
+							(context != PROCESS_UTILITY_TOPLEVEL || IsTransactionBlock()));
 			break;
 
 		case T_ClusterStmt:
diff --git a/src/backend/utils/mmgr/portalmem.c b/src/backend/utils/mmgr/portalmem.c
index d03b779407..d750425852 100644
--- a/src/backend/utils/mmgr/portalmem.c
+++ b/src/backend/utils/mmgr/portalmem.c
@@ -736,11 +736,8 @@ PreCommit_Portals(bool isPrepare)
 /*
  * Abort processing for portals.
  *
- * At this point we reset "active" status and run the cleanup hook if
- * present, but we can't release the portal's memory until the cleanup call.
- *
- * The reason we need to reset active is so that we can replace the unnamed
- * portal, else we'll fail to execute ROLLBACK when it arrives.
+ * At this point we run the cleanup hook if present, but we can't release the
+ * portal's memory until the cleanup call.
  */
 void
 AtAbort_Portals(void)
@@ -754,17 +751,6 @@ AtAbort_Portals(void)
 	{
 		Portal		portal = hentry->portal;
 
-		/*
-		 * See similar code in AtSubAbort_Portals().  This would fire if code
-		 * orchestrating multiple top-level transactions within a portal, such
-		 * as VACUUM, caught errors and continued under the same portal with a
-		 * fresh transaction.  No part of core PostgreSQL functions that way.
-		 * XXX Such code would wish the portal to remain ACTIVE, as in
-		 * PreCommit_Portals().
-		 */
-		if (portal->status == PORTAL_ACTIVE)
-			MarkPortalFailed(portal);
-
 		/*
 		 * Do nothing else to cursors held over from a previous transaction.
 		 */
@@ -799,14 +785,6 @@ AtAbort_Portals(void)
 		 * PortalDrop.
 		 */
 		portal->resowner = NULL;
-
-		/*
-		 * Although we can't delete the portal data structure proper, we can
-		 * release any memory in subsidiary contexts, such as executor state.
-		 * The cleanup hook was the last thing that might have needed data
-		 * there.
-		 */
-		MemoryContextDeleteChildren(PortalGetHeapMemory(portal));
 	}
 }
 
@@ -826,6 +804,19 @@ AtCleanup_Portals(void)
 	{
 		Portal		portal = hentry->portal;
 
+		/*
+		 * Do not touch active portals --- this can only happen in the case of
+		 * a multi-transaction command.
+		 *
+		 * Note however that any resource owner attached to such a portal is
+		 * still going to go away, so don't leave a dangling pointer.
+		 */
+		if (portal->status == PORTAL_ACTIVE)
+		{
+			portal->resowner = NULL;
+			continue;
+		}
+
 		/* Do nothing to cursors held over from a previous transaction */
 		if (portal->createSubid == InvalidSubTransactionId)
 		{
@@ -1155,3 +1146,22 @@ ThereAreNoReadyPortals(void)
 
 	return true;
 }
+
+bool
+ThereArePinnedPortals(void)
+{
+	HASH_SEQ_STATUS status;
+	PortalHashEnt *hentry;
+
+	hash_seq_init(&status, PortalHashTable);
+
+	while ((hentry = (PortalHashEnt *) hash_seq_search(&status)) != NULL)
+	{
+		Portal		portal = hentry->portal;
+
+		if (portal->portalPinned)
+			return true;
+	}
+
+	return false;
+}
diff --git a/src/include/commands/defrem.h b/src/include/commands/defrem.h
index 52cbf61ccb..b03f5b6a95 100644
--- a/src/include/commands/defrem.h
+++ b/src/include/commands/defrem.h
@@ -58,8 +58,8 @@ extern ObjectAddress CreateTransform(CreateTransformStmt *stmt);
 extern void DropTransformById(Oid transformOid);
 extern void IsThereFunctionInNamespace(const char *proname, int pronargs,
 						   oidvector *proargtypes, Oid nspOid);
-extern void ExecuteDoStmt(DoStmt *stmt);
-extern void ExecuteCallStmt(ParseState *pstate, CallStmt *stmt);
+extern void ExecuteDoStmt(DoStmt *stmt, bool atomic);
+extern void ExecuteCallStmt(ParseState *pstate, CallStmt *stmt, bool atomic);
 extern Oid	get_cast_oid(Oid sourcetypeid, Oid targettypeid, bool missing_ok);
 extern Oid	get_transform_oid(Oid type_id, Oid lang_id, bool missing_ok);
 extern void interpret_function_parameter_list(ParseState *pstate,
diff --git a/src/include/executor/spi.h b/src/include/executor/spi.h
index acade7e92e..e38158c54e 100644
--- a/src/include/executor/spi.h
+++ b/src/include/executor/spi.h
@@ -78,6 +78,7 @@ extern PGDLLIMPORT SPITupleTable *SPI_tuptable;
 extern PGDLLIMPORT int SPI_result;
 
 extern int	SPI_connect(void);
+extern int	SPI_set_nonatomic(void);
 extern int	SPI_finish(void);
 extern int	SPI_execute(const char *src, bool read_only, long tcount);
 extern int SPI_execute_plan(SPIPlanPtr plan, Datum *Values, const char *Nulls,
@@ -156,6 +157,10 @@ extern int	SPI_register_relation(EphemeralNamedRelation enr);
 extern int	SPI_unregister_relation(const char *name);
 extern int	SPI_register_trigger_data(TriggerData *tdata);
 
+extern int	SPI_start_transaction(void);
+extern int	SPI_commit(void);
+extern int	SPI_rollback(void);
+
 extern void AtEOXact_SPI(bool isCommit);
 extern void AtEOSubXact_SPI(bool isCommit, SubTransactionId mySubid);
 
diff --git a/src/include/executor/spi_priv.h b/src/include/executor/spi_priv.h
index 8fae755418..9dc8af22e4 100644
--- a/src/include/executor/spi_priv.h
+++ b/src/include/executor/spi_priv.h
@@ -36,6 +36,10 @@ typedef struct
 	MemoryContext savedcxt;		/* context of SPI_connect's caller */
 	SubTransactionId connectSubid;	/* ID of connecting subtransaction */
 	QueryEnvironment *queryEnv; /* query environment setup for SPI level */
+
+	/* transaction management support */
+	bool		atomic;			/* atomic execution context, does not allow transactions */
+	bool		internal_xact;	/* SPI-managed transaction boundary, skip cleanup */
 } _SPI_connection;
 
 /*
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index c5b5115f5b..6dcd51e958 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -500,7 +500,8 @@ typedef enum NodeTag
 	T_FdwRoutine,				/* in foreign/fdwapi.h */
 	T_IndexAmRoutine,			/* in access/amapi.h */
 	T_TsmRoutine,				/* in access/tsmapi.h */
-	T_ForeignKeyCacheInfo		/* in utils/rel.h */
+	T_ForeignKeyCacheInfo,		/* in utils/rel.h */
+	T_CallContext				/* in nodes/parsenodes.h */
 } NodeTag;
 
 /*
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 2eaa6b2774..cb1afd68f8 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2803,6 +2803,7 @@ typedef struct InlineCodeBlock
 	char	   *source_text;	/* source text of anonymous code block */
 	Oid			langOid;		/* OID of selected language */
 	bool		langIsTrusted;	/* trusted property of the language */
+	bool		atomic;			/* atomic execution context */
 } InlineCodeBlock;
 
 /* ----------------------
@@ -2815,6 +2816,12 @@ typedef struct CallStmt
 	FuncCall   *funccall;
 } CallStmt;
 
+typedef struct CallContext
+{
+	NodeTag		type;
+	bool		atomic;
+} CallContext;
+
 /* ----------------------
  *		Alter Object Rename Statement
  * ----------------------
diff --git a/src/include/utils/portal.h b/src/include/utils/portal.h
index cb6f00081d..cdbe7323d8 100644
--- a/src/include/utils/portal.h
+++ b/src/include/utils/portal.h
@@ -237,5 +237,6 @@ extern PlannedStmt *PortalGetPrimaryStmt(Portal portal);
 extern void PortalCreateHoldStore(Portal portal);
 extern void PortalHashTableDeleteAll(void);
 extern bool ThereAreNoReadyPortals(void);
+extern bool ThereArePinnedPortals(void);
 
 #endif							/* PORTAL_H */
diff --git a/src/pl/plperl/GNUmakefile b/src/pl/plperl/GNUmakefile
index b829027d05..933abb47c4 100644
--- a/src/pl/plperl/GNUmakefile
+++ b/src/pl/plperl/GNUmakefile
@@ -55,7 +55,7 @@ endif # win32
 SHLIB_LINK = $(perl_embed_ldflags)
 
 REGRESS_OPTS = --dbname=$(PL_TESTDB) --load-extension=plperl  --load-extension=plperlu
-REGRESS = plperl plperl_lc plperl_trigger plperl_shared plperl_elog plperl_util plperl_init plperlu plperl_array plperl_call
+REGRESS = plperl plperl_lc plperl_trigger plperl_shared plperl_elog plperl_util plperl_init plperlu plperl_array plperl_call plperl_transaction
 # if Perl can support two interpreters in one backend,
 # test plperl-and-plperlu cases
 ifneq ($(PERL),)
diff --git a/src/pl/plperl/SPI.xs b/src/pl/plperl/SPI.xs
index d9e6f579d4..dc9ddedc8f 100644
--- a/src/pl/plperl/SPI.xs
+++ b/src/pl/plperl/SPI.xs
@@ -17,6 +17,7 @@
 #define PG_NEED_PERL_XSUB_H
 #include "plperl.h"
 #include "plperl_helpers.h"
+#include "executor/spi.h"
 
 
 MODULE = PostgreSQL::InServer::SPI PREFIX = spi_
@@ -152,6 +153,17 @@ spi_spi_cursor_close(sv)
 		plperl_spi_cursor_close(cursor);
 		pfree(cursor);
 
+void
+spi_spi_commit()
+	CODE:
+		SPI_commit();
+		SPI_start_transaction();
+
+void
+spi_spi_rollback()
+	CODE:
+		SPI_rollback();
+		SPI_start_transaction();
 
 BOOT:
     items = 0;  /* avoid 'unused variable' warning */
diff --git a/src/pl/plperl/expected/plperl_transaction.out b/src/pl/plperl/expected/plperl_transaction.out
new file mode 100644
index 0000000000..f7378ce600
--- /dev/null
+++ b/src/pl/plperl/expected/plperl_transaction.out
@@ -0,0 +1,94 @@
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+DO
+LANGUAGE plperl
+$$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+return 1;
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/Perl function "transaction_test2"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query("CALL transaction_test1()");
+return 1;
+$$;
+-- FIXME
+--SELECT transaction_test3();
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query('DO LANGUAGE plperl $x$ spi_commit(); $x$');
+return 1;
+$$;
+-- FIXME
+--SELECT transaction_test4();
+DROP TABLE test1;
diff --git a/src/pl/plperl/plperl.c b/src/pl/plperl/plperl.c
index 9f5313235f..68592033f7 100644
--- a/src/pl/plperl/plperl.c
+++ b/src/pl/plperl/plperl.c
@@ -1931,6 +1931,8 @@ plperl_inline_handler(PG_FUNCTION_ARGS)
 
 		if (SPI_connect() != SPI_OK_CONNECT)
 			elog(ERROR, "could not connect to SPI manager");
+		if (!codeblock->atomic)
+			SPI_set_nonatomic();
 
 		select_perl_context(desc.lanpltrusted);
 
@@ -2409,6 +2411,10 @@ plperl_func_handler(PG_FUNCTION_ARGS)
 	current_call_data->prodesc = prodesc;
 	increment_prodesc_refcount(prodesc);
 
+	if (prodesc->result_oid == InvalidOid &&
+		!castNode(CallContext, fcinfo->context)->atomic)
+		SPI_set_nonatomic();
+
 	/* Set a callback for error reporting */
 	pl_error_context.callback = plperl_exec_callback;
 	pl_error_context.previous = error_context_stack;
diff --git a/src/pl/plperl/sql/plperl_transaction.sql b/src/pl/plperl/sql/plperl_transaction.sql
new file mode 100644
index 0000000000..5f15691cfc
--- /dev/null
+++ b/src/pl/plperl/sql/plperl_transaction.sql
@@ -0,0 +1,88 @@
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+DO
+LANGUAGE plperl
+$$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+return 1;
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query("CALL transaction_test1()");
+return 1;
+$$;
+
+-- FIXME
+--SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query('DO LANGUAGE plperl $x$ spi_commit(); $x$');
+return 1;
+$$;
+
+-- FIXME
+--SELECT transaction_test4();
+
+
+DROP TABLE test1;
diff --git a/src/pl/plpgsql/src/pl_exec.c b/src/pl/plpgsql/src/pl_exec.c
index ec480cb0ba..b8b0df21de 100644
--- a/src/pl/plpgsql/src/pl_exec.c
+++ b/src/pl/plpgsql/src/pl_exec.c
@@ -215,6 +215,10 @@ static int exec_stmt_dynexecute(PLpgSQL_execstate *estate,
 					 PLpgSQL_stmt_dynexecute *stmt);
 static int exec_stmt_dynfors(PLpgSQL_execstate *estate,
 				  PLpgSQL_stmt_dynfors *stmt);
+static int exec_stmt_commit(PLpgSQL_execstate *estate,
+				PLpgSQL_stmt_commit *stmt);
+static int exec_stmt_rollback(PLpgSQL_execstate *estate,
+				PLpgSQL_stmt_rollback *stmt);
 
 static void plpgsql_estate_setup(PLpgSQL_execstate *estate,
 					 PLpgSQL_function *func,
@@ -1652,6 +1656,14 @@ exec_stmt(PLpgSQL_execstate *estate, PLpgSQL_stmt *stmt)
 			rc = exec_stmt_close(estate, (PLpgSQL_stmt_close *) stmt);
 			break;
 
+		case PLPGSQL_STMT_COMMIT:
+			rc = exec_stmt_commit(estate, (PLpgSQL_stmt_commit *) stmt);
+			break;
+
+		case PLPGSQL_STMT_ROLLBACK:
+			rc = exec_stmt_rollback(estate, (PLpgSQL_stmt_rollback *) stmt);
+			break;
+
 		default:
 			estate->err_stmt = save_estmt;
 			elog(ERROR, "unrecognized cmdtype: %d", stmt->cmd_type);
@@ -4356,6 +4368,57 @@ exec_stmt_close(PLpgSQL_execstate *estate, PLpgSQL_stmt_close *stmt)
 	return PLPGSQL_RC_OK;
 }
 
+/*
+ * exec_stmt_commit
+ *
+ * Commit the transaction.
+ */
+static int
+exec_stmt_commit(PLpgSQL_execstate *estate, PLpgSQL_stmt_commit *stmt)
+{
+	/*
+	 * XXX This could be implemented by converting the pinned portals to
+	 * holdable ones and organizing the cleanup separately.
+	 */
+	if (ThereArePinnedPortals())
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("committing inside a cursor loop is not supported")));
+
+	SPI_commit();
+	SPI_start_transaction();
+
+	estate->simple_eval_estate = NULL;
+	plpgsql_create_econtext(estate);
+
+	return PLPGSQL_RC_OK;
+}
+
+/*
+ * exec_stmt_rollback
+ *
+ * Abort the transaction.
+ */
+static int
+exec_stmt_rollback(PLpgSQL_execstate *estate, PLpgSQL_stmt_rollback *stmt)
+{
+	/*
+	 * Unlike the COMMIT case above, this might not make sense at all,
+	 * especially if the query driving the cursor loop has side effects.
+	 */
+	if (ThereArePinnedPortals())
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("cannot abort transaction inside a cursor loop")));
+
+	SPI_rollback();
+	SPI_start_transaction();
+
+	estate->simple_eval_estate = NULL;
+	plpgsql_create_econtext(estate);
+
+	return PLPGSQL_RC_OK;
+}
 
 /* ----------
  * exec_assign_expr			Put an expression's result into a variable.
@@ -6857,8 +6920,7 @@ plpgsql_xact_cb(XactEvent event, void *arg)
 	 */
 	if (event == XACT_EVENT_COMMIT || event == XACT_EVENT_PREPARE)
 	{
-		/* Shouldn't be any econtext stack entries left at commit */
-		Assert(simple_econtext_stack == NULL);
+		simple_econtext_stack = NULL;
 
 		if (shared_simple_eval_estate)
 			FreeExecutorState(shared_simple_eval_estate);
diff --git a/src/pl/plpgsql/src/pl_funcs.c b/src/pl/plpgsql/src/pl_funcs.c
index 23f54e1c21..a3a45916d1 100644
--- a/src/pl/plpgsql/src/pl_funcs.c
+++ b/src/pl/plpgsql/src/pl_funcs.c
@@ -284,6 +284,10 @@ plpgsql_stmt_typename(PLpgSQL_stmt *stmt)
 			return "CLOSE";
 		case PLPGSQL_STMT_PERFORM:
 			return "PERFORM";
+		case PLPGSQL_STMT_COMMIT:
+			return "COMMIT";
+		case PLPGSQL_STMT_ROLLBACK:
+			return "ROLLBACK";
 	}
 
 	return "unknown";
@@ -363,6 +367,8 @@ static void free_open(PLpgSQL_stmt_open *stmt);
 static void free_fetch(PLpgSQL_stmt_fetch *stmt);
 static void free_close(PLpgSQL_stmt_close *stmt);
 static void free_perform(PLpgSQL_stmt_perform *stmt);
+static void free_commit(PLpgSQL_stmt_commit *stmt);
+static void free_rollback(PLpgSQL_stmt_rollback *stmt);
 static void free_expr(PLpgSQL_expr *expr);
 
 
@@ -443,6 +449,12 @@ free_stmt(PLpgSQL_stmt *stmt)
 		case PLPGSQL_STMT_PERFORM:
 			free_perform((PLpgSQL_stmt_perform *) stmt);
 			break;
+		case PLPGSQL_STMT_COMMIT:
+			free_commit((PLpgSQL_stmt_commit *) stmt);
+			break;
+		case PLPGSQL_STMT_ROLLBACK:
+			free_rollback((PLpgSQL_stmt_rollback *) stmt);
+			break;
 		default:
 			elog(ERROR, "unrecognized cmd_type: %d", stmt->cmd_type);
 			break;
@@ -590,6 +602,16 @@ free_perform(PLpgSQL_stmt_perform *stmt)
 	free_expr(stmt->expr);
 }
 
+static void
+free_commit(PLpgSQL_stmt_commit *stmt)
+{
+}
+
+static void
+free_rollback(PLpgSQL_stmt_rollback *stmt)
+{
+}
+
 static void
 free_exit(PLpgSQL_stmt_exit *stmt)
 {
@@ -777,6 +799,8 @@ static void dump_fetch(PLpgSQL_stmt_fetch *stmt);
 static void dump_cursor_direction(PLpgSQL_stmt_fetch *stmt);
 static void dump_close(PLpgSQL_stmt_close *stmt);
 static void dump_perform(PLpgSQL_stmt_perform *stmt);
+static void dump_commit(PLpgSQL_stmt_commit *stmt);
+static void dump_rollback(PLpgSQL_stmt_rollback *stmt);
 static void dump_expr(PLpgSQL_expr *expr);
 
 
@@ -867,6 +891,12 @@ dump_stmt(PLpgSQL_stmt *stmt)
 		case PLPGSQL_STMT_PERFORM:
 			dump_perform((PLpgSQL_stmt_perform *) stmt);
 			break;
+		case PLPGSQL_STMT_COMMIT:
+			dump_commit((PLpgSQL_stmt_commit *) stmt);
+			break;
+		case PLPGSQL_STMT_ROLLBACK:
+			dump_rollback((PLpgSQL_stmt_rollback *) stmt);
+			break;
 		default:
 			elog(ERROR, "unrecognized cmd_type: %d", stmt->cmd_type);
 			break;
@@ -1243,6 +1273,20 @@ dump_perform(PLpgSQL_stmt_perform *stmt)
 	printf("\n");
 }
 
+static void
+dump_commit(PLpgSQL_stmt_commit *stmt)
+{
+	dump_ind();
+	printf("COMMIT\n");
+}
+
+static void
+dump_rollback(PLpgSQL_stmt_rollback *stmt)
+{
+	dump_ind();
+	printf("ROLLBACK\n");
+}
+
 static void
 dump_exit(PLpgSQL_stmt_exit *stmt)
 {
diff --git a/src/pl/plpgsql/src/pl_gram.y b/src/pl/plpgsql/src/pl_gram.y
index 94f1f58593..e661750176 100644
--- a/src/pl/plpgsql/src/pl_gram.y
+++ b/src/pl/plpgsql/src/pl_gram.y
@@ -199,6 +199,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %type <stmt>	stmt_return stmt_raise stmt_assert stmt_execsql
 %type <stmt>	stmt_dynexecute stmt_for stmt_perform stmt_getdiag
 %type <stmt>	stmt_open stmt_fetch stmt_move stmt_close stmt_null
+%type <stmt>	stmt_commit stmt_rollback
 %type <stmt>	stmt_case stmt_foreach_a
 
 %type <list>	proc_exceptions
@@ -261,6 +262,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %token <keyword>	K_COLLATE
 %token <keyword>	K_COLUMN
 %token <keyword>	K_COLUMN_NAME
+%token <keyword>	K_COMMIT
 %token <keyword>	K_CONSTANT
 %token <keyword>	K_CONSTRAINT
 %token <keyword>	K_CONSTRAINT_NAME
@@ -326,6 +328,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %token <keyword>	K_RETURN
 %token <keyword>	K_RETURNED_SQLSTATE
 %token <keyword>	K_REVERSE
+%token <keyword>	K_ROLLBACK
 %token <keyword>	K_ROW_COUNT
 %token <keyword>	K_ROWTYPE
 %token <keyword>	K_SCHEMA
@@ -898,6 +901,10 @@ proc_stmt		: pl_block ';'
 						{ $$ = $1; }
 				| stmt_null
 						{ $$ = $1; }
+				| stmt_commit
+						{ $$ = $1; }
+				| stmt_rollback
+						{ $$ = $1; }
 				;
 
 stmt_perform	: K_PERFORM expr_until_semi
@@ -2174,6 +2181,31 @@ stmt_null		: K_NULL ';'
 					}
 				;
 
+stmt_commit		: K_COMMIT ';'
+					{
+						PLpgSQL_stmt_commit *new;
+
+						new = palloc(sizeof(PLpgSQL_stmt_commit));
+						new->cmd_type = PLPGSQL_STMT_COMMIT;
+						new->lineno = plpgsql_location_to_lineno(@1);
+
+						$$ = (PLpgSQL_stmt *)new;
+					}
+				;
+
+stmt_rollback	: K_ROLLBACK ';'
+					{
+						PLpgSQL_stmt_rollback *new;
+
+						new = palloc(sizeof(PLpgSQL_stmt_rollback));
+						new->cmd_type = PLPGSQL_STMT_ROLLBACK;
+						new->lineno = plpgsql_location_to_lineno(@1);
+
+						$$ = (PLpgSQL_stmt *)new;
+					}
+				;
+
+
 cursor_variable	: T_DATUM
 					{
 						/*
@@ -2410,6 +2442,7 @@ unreserved_keyword	:
 				| K_COLLATE
 				| K_COLUMN
 				| K_COLUMN_NAME
+				| K_COMMIT
 				| K_CONSTANT
 				| K_CONSTRAINT
 				| K_CONSTRAINT_NAME
@@ -2461,6 +2494,7 @@ unreserved_keyword	:
 				| K_RETURN
 				| K_RETURNED_SQLSTATE
 				| K_REVERSE
+				| K_ROLLBACK
 				| K_ROW_COUNT
 				| K_ROWTYPE
 				| K_SCHEMA
diff --git a/src/pl/plpgsql/src/pl_handler.c b/src/pl/plpgsql/src/pl_handler.c
index 1ebb7a7b5e..6857b0375e 100644
--- a/src/pl/plpgsql/src/pl_handler.c
+++ b/src/pl/plpgsql/src/pl_handler.c
@@ -255,7 +255,12 @@ plpgsql_call_handler(PG_FUNCTION_ARGS)
 			retval = (Datum) 0;
 		}
 		else
+		{
+			if (func->fn_rettype == InvalidOid &&
+				!castNode(CallContext, fcinfo->context)->atomic)
+				SPI_set_nonatomic();
 			retval = plpgsql_exec_function(func, fcinfo, NULL);
+		}
 	}
 	PG_CATCH();
 	{
@@ -304,6 +309,9 @@ plpgsql_inline_handler(PG_FUNCTION_ARGS)
 	if ((rc = SPI_connect()) != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed: %s", SPI_result_code_string(rc));
 
+	if (!codeblock->atomic)
+		SPI_set_nonatomic();
+
 	/* Compile the anonymous code block */
 	func = plpgsql_compile_inline(codeblock->source_text);
 
diff --git a/src/pl/plpgsql/src/pl_scanner.c b/src/pl/plpgsql/src/pl_scanner.c
index 553be8c93c..a172031db2 100644
--- a/src/pl/plpgsql/src/pl_scanner.c
+++ b/src/pl/plpgsql/src/pl_scanner.c
@@ -106,6 +106,7 @@ static const ScanKeyword unreserved_keywords[] = {
 	PG_KEYWORD("collate", K_COLLATE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("column", K_COLUMN, UNRESERVED_KEYWORD)
 	PG_KEYWORD("column_name", K_COLUMN_NAME, UNRESERVED_KEYWORD)
+	PG_KEYWORD("commit", K_COMMIT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constant", K_CONSTANT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constraint", K_CONSTRAINT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constraint_name", K_CONSTRAINT_NAME, UNRESERVED_KEYWORD)
@@ -158,6 +159,7 @@ static const ScanKeyword unreserved_keywords[] = {
 	PG_KEYWORD("return", K_RETURN, UNRESERVED_KEYWORD)
 	PG_KEYWORD("returned_sqlstate", K_RETURNED_SQLSTATE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("reverse", K_REVERSE, UNRESERVED_KEYWORD)
+	PG_KEYWORD("rollback", K_ROLLBACK, UNRESERVED_KEYWORD)
 	PG_KEYWORD("row_count", K_ROW_COUNT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("rowtype", K_ROWTYPE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("schema", K_SCHEMA, UNRESERVED_KEYWORD)
diff --git a/src/pl/plpgsql/src/plpgsql.h b/src/pl/plpgsql/src/plpgsql.h
index 2b19948562..8494a4374d 100644
--- a/src/pl/plpgsql/src/plpgsql.h
+++ b/src/pl/plpgsql/src/plpgsql.h
@@ -105,7 +105,9 @@ typedef enum PLpgSQL_stmt_type
 	PLPGSQL_STMT_OPEN,
 	PLPGSQL_STMT_FETCH,
 	PLPGSQL_STMT_CLOSE,
-	PLPGSQL_STMT_PERFORM
+	PLPGSQL_STMT_PERFORM,
+	PLPGSQL_STMT_COMMIT,
+	PLPGSQL_STMT_ROLLBACK
 } PLpgSQL_stmt_type;
 
 /*
@@ -433,6 +435,24 @@ typedef struct PLpgSQL_stmt_perform
 	PLpgSQL_expr *expr;
 } PLpgSQL_stmt_perform;
 
+/*
+ * COMMIT statement
+ */
+typedef struct PLpgSQL_stmt_commit
+{
+	PLpgSQL_stmt_type cmd_type;
+	int			lineno;
+} PLpgSQL_stmt_commit;
+
+/*
+ * ROLLBACK statement
+ */
+typedef struct PLpgSQL_stmt_rollback
+{
+	PLpgSQL_stmt_type cmd_type;
+	int			lineno;
+} PLpgSQL_stmt_rollback;
+
 /*
  * GET DIAGNOSTICS item
  */
diff --git a/src/pl/plpython/Makefile b/src/pl/plpython/Makefile
index cc91afebde..d09910835d 100644
--- a/src/pl/plpython/Makefile
+++ b/src/pl/plpython/Makefile
@@ -90,6 +90,7 @@ REGRESS = \
 	plpython_quote \
 	plpython_composite \
 	plpython_subtransaction \
+	plpython_transaction \
 	plpython_drop
 
 REGRESS_PLPYTHON3_MANGLE := $(REGRESS)
diff --git a/src/pl/plpython/expected/plpython_test.out b/src/pl/plpython/expected/plpython_test.out
index 847e4cc412..39b994f446 100644
--- a/src/pl/plpython/expected/plpython_test.out
+++ b/src/pl/plpython/expected/plpython_test.out
@@ -48,6 +48,7 @@ select module_contents();
  Error
  Fatal
  SPIError
+ commit
  cursor
  debug
  error
@@ -60,10 +61,11 @@ select module_contents();
  quote_ident
  quote_literal
  quote_nullable
+ rollback
  spiexceptions
  subtransaction
  warning
-(18 rows)
+(20 rows)
 
 CREATE FUNCTION elog_test_basic() RETURNS void
 AS $$
diff --git a/src/pl/plpython/expected/plpython_transaction.out b/src/pl/plpython/expected/plpython_transaction.out
new file mode 100644
index 0000000000..ff07bce193
--- /dev/null
+++ b/src/pl/plpython/expected/plpython_transaction.out
@@ -0,0 +1,104 @@
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+DO
+LANGUAGE plpythonu
+$$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+return 1
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/Python function "transaction_test2"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("CALL transaction_test1()")
+return 1
+$$;
+SELECT transaction_test3();
+ERROR:  spiexceptions.InvalidTransactionTermination: invalid transaction termination
+CONTEXT:  Traceback (most recent call last):
+  PL/Python function "transaction_test3", line 2, in <module>
+    plpy.execute("CALL transaction_test1()")
+PL/Python function "transaction_test3"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$")
+return 1
+$$;
+SELECT transaction_test4();
+ERROR:  spiexceptions.InvalidTransactionTermination: invalid transaction termination
+CONTEXT:  Traceback (most recent call last):
+  PL/Python function "transaction_test4", line 2, in <module>
+    plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$")
+PL/Python function "transaction_test4"
+-- commit inside subtransaction (prohibited)
+DO LANGUAGE plpythonu $$
+with plpy.subtransaction():
+    plpy.commit()
+$$;
+WARNING:  forcibly aborting a subtransaction that has not been exited
+ERROR:  cannot commit while a subtransaction is active
+CONTEXT:  PL/Python anonymous code block
+DROP TABLE test1;
diff --git a/src/pl/plpython/plpy_main.c b/src/pl/plpython/plpy_main.c
index 695de30583..254ab37359 100644
--- a/src/pl/plpython/plpy_main.c
+++ b/src/pl/plpython/plpy_main.c
@@ -262,6 +262,9 @@ plpython_call_handler(PG_FUNCTION_ARGS)
 		else
 		{
 			proc = PLy_procedure_get(funcoid, InvalidOid, false);
+			if (proc->is_procedure &&
+				!castNode(CallContext, fcinfo->context)->atomic)
+					SPI_set_nonatomic();
 			exec_ctx->curr_proc = proc;
 			retval = PLy_exec_function(fcinfo, proc);
 		}
@@ -305,6 +308,8 @@ plpython_inline_handler(PG_FUNCTION_ARGS)
 	/* Note: SPI_finish() happens in plpy_exec.c, which is dubious design */
 	if (SPI_connect() != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed");
+	if (!codeblock->atomic)
+		SPI_set_nonatomic();
 
 	MemSet(&fake_fcinfo, 0, sizeof(fake_fcinfo));
 	MemSet(&flinfo, 0, sizeof(flinfo));
@@ -435,7 +440,7 @@ PLy_push_execution_context(void)
 	PLyExecutionContext *context;
 
 	context = (PLyExecutionContext *)
-		MemoryContextAlloc(TopTransactionContext, sizeof(PLyExecutionContext));
+		MemoryContextAlloc(PortalContext, sizeof(PLyExecutionContext));
 	context->curr_proc = NULL;
 	context->scratch_ctx = NULL;
 	context->next = PLy_execution_contexts;
diff --git a/src/pl/plpython/plpy_plpymodule.c b/src/pl/plpython/plpy_plpymodule.c
index 23f99e20ca..b9b9e423a7 100644
--- a/src/pl/plpython/plpy_plpymodule.c
+++ b/src/pl/plpython/plpy_plpymodule.c
@@ -6,8 +6,10 @@
 
 #include "postgres.h"
 
+#include "access/xact.h"
 #include "mb/pg_wchar.h"
 #include "utils/builtins.h"
+#include "utils/snapmgr.h"
 
 #include "plpython.h"
 
@@ -41,6 +43,8 @@ static PyObject *PLy_fatal(PyObject *self, PyObject *args, PyObject *kw);
 static PyObject *PLy_quote_literal(PyObject *self, PyObject *args);
 static PyObject *PLy_quote_nullable(PyObject *self, PyObject *args);
 static PyObject *PLy_quote_ident(PyObject *self, PyObject *args);
+static PyObject *PLy_commit(PyObject *self, PyObject *args);
+static PyObject *PLy_rollback(PyObject *self, PyObject *args);
 
 
 /* A list of all known exceptions, generated from backend/utils/errcodes.txt */
@@ -95,6 +99,12 @@ static PyMethodDef PLy_methods[] = {
 	 */
 	{"cursor", PLy_cursor, METH_VARARGS, NULL},
 
+	/*
+	 * transaction control
+	 */
+	{"commit", PLy_commit, METH_NOARGS, NULL},
+	{"rollback", PLy_rollback, METH_NOARGS, NULL},
+
 	{NULL, NULL, 0, NULL}
 };
 
@@ -577,3 +587,21 @@ PLy_output(volatile int level, PyObject *self, PyObject *args, PyObject *kw)
 	 */
 	Py_RETURN_NONE;
 }
+
+static PyObject *
+PLy_commit(PyObject *self, PyObject *args)
+{
+	SPI_commit();
+	SPI_start_transaction();
+
+	Py_RETURN_NONE;
+}
+
+static PyObject *
+PLy_rollback(PyObject *self, PyObject *args)
+{
+	SPI_rollback();
+	SPI_start_transaction();
+
+	Py_RETURN_NONE;
+}
diff --git a/src/pl/plpython/sql/plpython_transaction.sql b/src/pl/plpython/sql/plpython_transaction.sql
new file mode 100644
index 0000000000..0656aa1458
--- /dev/null
+++ b/src/pl/plpython/sql/plpython_transaction.sql
@@ -0,0 +1,87 @@
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+DO
+LANGUAGE plpythonu
+$$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+return 1
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("CALL transaction_test1()")
+return 1
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$")
+return 1
+$$;
+
+SELECT transaction_test4();
+
+
+-- commit inside subtransaction (prohibited)
+DO LANGUAGE plpythonu $$
+with plpy.subtransaction():
+    plpy.commit()
+$$;
+
+
+DROP TABLE test1;
diff --git a/src/pl/tcl/Makefile b/src/pl/tcl/Makefile
index 6a92a9b6aa..ef61ee596e 100644
--- a/src/pl/tcl/Makefile
+++ b/src/pl/tcl/Makefile
@@ -28,7 +28,7 @@ DATA = pltcl.control pltcl--1.0.sql pltcl--unpackaged--1.0.sql \
        pltclu.control pltclu--1.0.sql pltclu--unpackaged--1.0.sql
 
 REGRESS_OPTS = --dbname=$(PL_TESTDB) --load-extension=pltcl
-REGRESS = pltcl_setup pltcl_queries pltcl_call pltcl_start_proc pltcl_subxact pltcl_unicode
+REGRESS = pltcl_setup pltcl_queries pltcl_call pltcl_start_proc pltcl_subxact pltcl_unicode pltcl_transaction
 
 # Tcl on win32 ships with import libraries only for Microsoft Visual C++,
 # which are not compatible with mingw gcc. Therefore we need to build a
diff --git a/src/pl/tcl/expected/pltcl_transaction.out b/src/pl/tcl/expected/pltcl_transaction.out
new file mode 100644
index 0000000000..6ce900027c
--- /dev/null
+++ b/src/pl/tcl/expected/pltcl_transaction.out
@@ -0,0 +1,63 @@
+-- suppress CONTEXT so that function OIDs aren't in output
+\set VERBOSITY terse
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+return 1
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE pltcl
+AS $$
+spi_exec "CALL transaction_test1()"
+return 1
+$$;
+SELECT transaction_test3();
+ERROR:  invalid transaction termination
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+DROP TABLE test1;
diff --git a/src/pl/tcl/pltcl.c b/src/pl/tcl/pltcl.c
index e0792d93e1..0571755b4f 100644
--- a/src/pl/tcl/pltcl.c
+++ b/src/pl/tcl/pltcl.c
@@ -312,6 +312,10 @@ static int pltcl_SPI_lastoid(ClientData cdata, Tcl_Interp *interp,
 				  int objc, Tcl_Obj *const objv[]);
 static int pltcl_subtransaction(ClientData cdata, Tcl_Interp *interp,
 					 int objc, Tcl_Obj *const objv[]);
+static int pltcl_commit(ClientData cdata, Tcl_Interp *interp,
+					 int objc, Tcl_Obj *const objv[]);
+static int pltcl_rollback(ClientData cdata, Tcl_Interp *interp,
+					 int objc, Tcl_Obj *const objv[]);
 
 static void pltcl_subtrans_begin(MemoryContext oldcontext,
 					 ResourceOwner oldowner);
@@ -524,6 +528,10 @@ pltcl_init_interp(pltcl_interp_desc *interp_desc, Oid prolang, bool pltrusted)
 						 pltcl_SPI_lastoid, NULL, NULL);
 	Tcl_CreateObjCommand(interp, "subtransaction",
 						 pltcl_subtransaction, NULL, NULL);
+	Tcl_CreateObjCommand(interp, "commit",
+						 pltcl_commit, NULL, NULL);
+	Tcl_CreateObjCommand(interp, "rollback",
+						 pltcl_rollback, NULL, NULL);
 
 	/************************************************************
 	 * Call the appropriate start_proc, if there is one.
@@ -812,6 +820,10 @@ pltcl_func_handler(PG_FUNCTION_ARGS, pltcl_call_state *call_state,
 	prodesc = compile_pltcl_function(fcinfo->flinfo->fn_oid, InvalidOid,
 									 false, pltrusted);
 
+	if (prodesc->result_typid == InvalidOid &&
+		!castNode(CallContext, fcinfo->context)->atomic)
+		SPI_set_nonatomic();
+
 	call_state->prodesc = prodesc;
 	prodesc->fn_refcount++;
 
@@ -2935,6 +2947,38 @@ pltcl_subtransaction(ClientData cdata, Tcl_Interp *interp,
 }
 
 
+/**********************************************************************
+ * pltcl_commit()
+ *
+ * Commit the transaction and start a new one.
+ **********************************************************************/
+static int
+pltcl_commit(ClientData cdata, Tcl_Interp *interp,
+			 int objc, Tcl_Obj *const objv[])
+{
+	SPI_commit();
+	SPI_start_transaction();
+
+	return TCL_OK;
+}
+
+
+/**********************************************************************
+ * pltcl_rollback()
+ *
+ * Abort the transaction and start a new one.
+ **********************************************************************/
+static int
+pltcl_rollback(ClientData cdata, Tcl_Interp *interp,
+			   int objc, Tcl_Obj *const objv[])
+{
+	SPI_rollback();
+	SPI_start_transaction();
+
+	return TCL_OK;
+}
+
+
 /**********************************************************************
  * pltcl_set_tuple_values() - Set variables for all attributes
  *				  of a given tuple
diff --git a/src/pl/tcl/sql/pltcl_transaction.sql b/src/pl/tcl/sql/pltcl_transaction.sql
new file mode 100644
index 0000000000..14aed5844a
--- /dev/null
+++ b/src/pl/tcl/sql/pltcl_transaction.sql
@@ -0,0 +1,60 @@
+-- suppress CONTEXT so that function OIDs aren't in output
+\set VERBOSITY terse
+
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+return 1
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE pltcl
+AS $$
+spi_exec "CALL transaction_test1()"
+return 1
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+DROP TABLE test1;
diff --git a/src/test/regress/expected/plpgsql.out b/src/test/regress/expected/plpgsql.out
index d6e5bc3353..824977afc5 100644
--- a/src/test/regress/expected/plpgsql.out
+++ b/src/test/regress/expected/plpgsql.out
@@ -6077,7 +6077,248 @@ SELECT * FROM proc_test1;
  55
 (1 row)
 
+TRUNCATE proc_test1;
+CREATE PROCEDURE test_proc_transaction1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+CALL test_proc_transaction1();
+SELECT * FROM proc_test1;
+ a 
+---
+ 0
+ 2
+ 4
+ 6
+ 8
+(5 rows)
+
+TRUNCATE proc_test1;
+DO
+LANGUAGE plpgsql
+$$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+SELECT * FROM proc_test1;
+ a 
+---
+ 0
+ 2
+ 4
+ 6
+ 8
+(5 rows)
+
+-- transaction commands not allowed when called in transaction block
+START TRANSACTION;
+CALL test_proc_transaction1();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function test_proc_transaction1() line 6 at COMMIT
+COMMIT;
+START TRANSACTION;
+DO LANGUAGE plpgsql $$ BEGIN COMMIT; END $$;
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function inline_code_block line 1 at COMMIT
+COMMIT;
+TRUNCATE proc_test1;
+-- not allowed in a function
+CREATE FUNCTION test_proc_transaction2() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+    RETURN 1;
+END
+$$;
+SELECT test_proc_transaction2();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function test_proc_transaction2() line 6 at COMMIT
+SELECT * FROM proc_test1;
+ a 
+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION test_proc_transaction3() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    CALL test_proc_transaction1();
+    RETURN 1;
+END;
+$$;
+SELECT test_proc_transaction3();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function test_proc_transaction1() line 6 at COMMIT
+SQL statement "CALL test_proc_transaction1()"
+PL/pgSQL function test_proc_transaction3() line 3 at SQL statement
+SELECT * FROM proc_test1;
+ a 
+---
+(0 rows)
+
+-- DO block inside function
+CREATE FUNCTION test_proc_transaction4() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    EXECUTE 'DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$';
+    RETURN 1;
+END;
+$$;
+SELECT test_proc_transaction4();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function inline_code_block line 1 at COMMIT
+SQL statement "DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$"
+PL/pgSQL function test_proc_transaction4() line 3 at EXECUTE
+-- proconfig settings currently disallow transaction statements
+CREATE PROCEDURE test_proc_transaction5()
+LANGUAGE plpgsql
+SET work_mem = 555
+AS $$
+BEGIN
+    COMMIT;
+END;
+$$;
+CALL test_proc_transaction5();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function test_proc_transaction5() line 3 at COMMIT
+-- commit inside cursor loop
+CREATE TABLE proc_test2 (x int);
+INSERT INTO proc_test2 VALUES (0), (1), (2), (3), (4);
+TRUNCATE proc_test1;
+DO LANGUAGE plpgsql $$
+DECLARE
+    r RECORD;
+BEGIN
+    FOR r IN SELECT * FROM proc_test2 ORDER BY x LOOP
+        INSERT INTO proc_test1 (a) VALUES (r.x);
+        COMMIT;
+    END LOOP;
+END;
+$$;
+ERROR:  committing inside a cursor loop is not supported
+CONTEXT:  PL/pgSQL function inline_code_block line 7 at COMMIT
+SELECT * FROM proc_test1;
+ a 
+---
+(0 rows)
+
+-- rollback inside cursor loop
+TRUNCATE proc_test1;
+DO LANGUAGE plpgsql $$
+DECLARE
+    r RECORD;
+BEGIN
+    FOR r IN SELECT * FROM proc_test2 ORDER BY x LOOP
+        INSERT INTO proc_test1 (a) VALUES (r.x);
+        ROLLBACK;
+    END LOOP;
+END;
+$$;
+ERROR:  cannot abort transaction inside a cursor loop
+CONTEXT:  PL/pgSQL function inline_code_block line 7 at ROLLBACK
+SELECT * FROM proc_test1;
+ a 
+---
+(0 rows)
+
+-- commit inside block with exception handler
+TRUNCATE proc_test1;
+DO LANGUAGE plpgsql $$
+BEGIN
+    BEGIN
+        INSERT INTO proc_test1 (a) VALUES (1);
+        COMMIT;
+        INSERT INTO proc_test1 (a) VALUES (1/0);
+        COMMIT;
+    EXCEPTION
+        WHEN division_by_zero THEN
+            RAISE NOTICE 'caught division_by_zero';
+    END;
+END;
+$$;
+ERROR:  cannot commit while a subtransaction is active
+CONTEXT:  PL/pgSQL function inline_code_block line 5 at COMMIT
+SELECT * FROM proc_test1;
+ a 
+---
+(0 rows)
+
+-- rollback inside block with exception handler
+TRUNCATE proc_test1;
+DO LANGUAGE plpgsql $$
+BEGIN
+    BEGIN
+        INSERT INTO proc_test1 (a) VALUES (1);
+        ROLLBACK;
+        INSERT INTO proc_test1 (a) VALUES (1/0);
+        ROLLBACK;
+    EXCEPTION
+        WHEN division_by_zero THEN
+            RAISE NOTICE 'caught division_by_zero';
+    END;
+END;
+$$;
+ERROR:  cannot roll back while a subtransaction is active
+CONTEXT:  PL/pgSQL function inline_code_block line 5 at ROLLBACK
+SELECT * FROM proc_test1;
+ a 
+---
+(0 rows)
+
+-- COMMIT failures
+DO LANGUAGE plpgsql $$
+BEGIN
+    CREATE TABLE proc_test3 (y int UNIQUE DEFERRABLE INITIALLY DEFERRED);
+    COMMIT;
+    INSERT INTO proc_test3 (y) VALUES (1);
+    COMMIT;
+    INSERT INTO proc_test3 (y) VALUES (1);
+    INSERT INTO proc_test3 (y) VALUES (2);
+    COMMIT;
+    INSERT INTO proc_test3 (y) VALUES (3);  -- won't get here
+END;
+$$;
+ERROR:  duplicate key value violates unique constraint "proc_test3_y_key"
+DETAIL:  Key (y)=(1) already exists.
+CONTEXT:  PL/pgSQL function inline_code_block line 9 at COMMIT
+SELECT * FROM proc_test3;
+ y 
+---
+ 1
+(1 row)
+
 DROP PROCEDURE test_proc1;
 DROP PROCEDURE test_proc2;
 DROP PROCEDURE test_proc3;
+DROP PROCEDURE test_proc_transaction1;
 DROP TABLE proc_test1;
+DROP TABLE proc_test2;
+DROP TABLE proc_test3;
diff --git a/src/test/regress/sql/plpgsql.sql b/src/test/regress/sql/plpgsql.sql
index 1c355132b7..3cd61feb70 100644
--- a/src/test/regress/sql/plpgsql.sql
+++ b/src/test/regress/sql/plpgsql.sql
@@ -4864,8 +4864,222 @@ CREATE PROCEDURE test_proc3(x int)
 SELECT * FROM proc_test1;
 
 
+TRUNCATE proc_test1;
+
+CREATE PROCEDURE test_proc_transaction1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+CALL test_proc_transaction1();
+
+SELECT * FROM proc_test1;
+
+
+TRUNCATE proc_test1;
+
+DO
+LANGUAGE plpgsql
+$$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+SELECT * FROM proc_test1;
+
+
+-- transaction commands not allowed when called in transaction block
+START TRANSACTION;
+CALL test_proc_transaction1();
+COMMIT;
+
+START TRANSACTION;
+DO LANGUAGE plpgsql $$ BEGIN COMMIT; END $$;
+COMMIT;
+
+
+TRUNCATE proc_test1;
+
+-- not allowed in a function
+CREATE FUNCTION test_proc_transaction2() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO proc_test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+    RETURN 1;
+END
+$$;
+
+SELECT test_proc_transaction2();
+
+SELECT * FROM proc_test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION test_proc_transaction3() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    CALL test_proc_transaction1();
+    RETURN 1;
+END;
+$$;
+
+SELECT test_proc_transaction3();
+
+SELECT * FROM proc_test1;
+
+
+-- DO block inside function
+CREATE FUNCTION test_proc_transaction4() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    EXECUTE 'DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$';
+    RETURN 1;
+END;
+$$;
+
+SELECT test_proc_transaction4();
+
+
+-- proconfig settings currently disallow transaction statements
+CREATE PROCEDURE test_proc_transaction5()
+LANGUAGE plpgsql
+SET work_mem = 555
+AS $$
+BEGIN
+    COMMIT;
+END;
+$$;
+
+CALL test_proc_transaction5();
+
+
+-- commit inside cursor loop
+CREATE TABLE proc_test2 (x int);
+INSERT INTO proc_test2 VALUES (0), (1), (2), (3), (4);
+
+TRUNCATE proc_test1;
+
+DO LANGUAGE plpgsql $$
+DECLARE
+    r RECORD;
+BEGIN
+    FOR r IN SELECT * FROM proc_test2 ORDER BY x LOOP
+        INSERT INTO proc_test1 (a) VALUES (r.x);
+        COMMIT;
+    END LOOP;
+END;
+$$;
+
+SELECT * FROM proc_test1;
+
+
+-- rollback inside cursor loop
+TRUNCATE proc_test1;
+
+DO LANGUAGE plpgsql $$
+DECLARE
+    r RECORD;
+BEGIN
+    FOR r IN SELECT * FROM proc_test2 ORDER BY x LOOP
+        INSERT INTO proc_test1 (a) VALUES (r.x);
+        ROLLBACK;
+    END LOOP;
+END;
+$$;
+
+SELECT * FROM proc_test1;
+
+
+-- commit inside block with exception handler
+TRUNCATE proc_test1;
+
+DO LANGUAGE plpgsql $$
+BEGIN
+    BEGIN
+        INSERT INTO proc_test1 (a) VALUES (1);
+        COMMIT;
+        INSERT INTO proc_test1 (a) VALUES (1/0);
+        COMMIT;
+    EXCEPTION
+        WHEN division_by_zero THEN
+            RAISE NOTICE 'caught division_by_zero';
+    END;
+END;
+$$;
+
+SELECT * FROM proc_test1;
+
+
+-- rollback inside block with exception handler
+TRUNCATE proc_test1;
+
+DO LANGUAGE plpgsql $$
+BEGIN
+    BEGIN
+        INSERT INTO proc_test1 (a) VALUES (1);
+        ROLLBACK;
+        INSERT INTO proc_test1 (a) VALUES (1/0);
+        ROLLBACK;
+    EXCEPTION
+        WHEN division_by_zero THEN
+            RAISE NOTICE 'caught division_by_zero';
+    END;
+END;
+$$;
+
+SELECT * FROM proc_test1;
+
+
+-- COMMIT failures
+DO LANGUAGE plpgsql $$
+BEGIN
+    CREATE TABLE proc_test3 (y int UNIQUE DEFERRABLE INITIALLY DEFERRED);
+    COMMIT;
+    INSERT INTO proc_test3 (y) VALUES (1);
+    COMMIT;
+    INSERT INTO proc_test3 (y) VALUES (1);
+    INSERT INTO proc_test3 (y) VALUES (2);
+    COMMIT;
+    INSERT INTO proc_test3 (y) VALUES (3);  -- won't get here
+END;
+$$;
+
+SELECT * FROM proc_test3;
+
+
 DROP PROCEDURE test_proc1;
 DROP PROCEDURE test_proc2;
 DROP PROCEDURE test_proc3;
+DROP PROCEDURE test_proc_transaction1;
 
 DROP TABLE proc_test1;
+DROP TABLE proc_test2;
+DROP TABLE proc_test3;

base-commit: 979a36c3894db0a4b0d6b4b20fc861a0bbe3271c
-- 
2.15.1

#31Merlin Moncure
mmoncure@gmail.com
In reply to: Peter Eisentraut (#30)
Re: [HACKERS] Transaction control in procedures

On Wed, Dec 6, 2017 at 8:41 AM, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

On 12/5/17 13:33, Robert Haas wrote:

On Tue, Dec 5, 2017 at 1:25 PM, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

I think ROLLBACK in a cursor loop might not make sense, because the
cursor query itself could have side effects, so a rollback would have to
roll back the entire loop. That might need more refined analysis before
it could be allowed.

COMMIT really has the same problem; if the cursor query has side
effects, you can't commit those side effects piecemeal as the loop
executed and have things behave sanely.

The first COMMIT inside the loop would commit the cursor query. This
isn't all that different from what you'd get now if you coded this
manually using holdable cursors or just plain client code. Clearly, you
can create a mess if the loop body interacts with the loop expression,
but that's already the case.

But if you coded something like this yourself now and ran a ROLLBACK
inside the loop, the holdable cursor would disappear (unless previously
committed), so you couldn't proceed with the loop.

The SQL standard for persistent stored modules explicitly prohibits
COMMIT and ROLLBACK in cursor loop bodies. But I think people will
eventually want it.

The may want it, but silently promoting all cursors to held ones is
not the way to give it to them, unless we narrow it down the the
'for-loop derived cursor' only. Even then we should consider syntax
decoration:

FOR x IN SELECT .... WITH HOLD
LOOP

END LOOP;

merlin

#32Andrew Dunstan
andrew.dunstan@2ndquadrant.com
In reply to: Peter Eisentraut (#30)
Re: [HACKERS] Transaction control in procedures

On 12/06/2017 09:41 AM, Peter Eisentraut wrote:

On 12/5/17 13:33, Robert Haas wrote:

On Tue, Dec 5, 2017 at 1:25 PM, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

I think ROLLBACK in a cursor loop might not make sense, because the
cursor query itself could have side effects, so a rollback would have to
roll back the entire loop. That might need more refined analysis before
it could be allowed.

COMMIT really has the same problem; if the cursor query has side
effects, you can't commit those side effects piecemeal as the loop
executed and have things behave sanely.

The first COMMIT inside the loop would commit the cursor query. This
isn't all that different from what you'd get now if you coded this
manually using holdable cursors or just plain client code. Clearly, you
can create a mess if the loop body interacts with the loop expression,
but that's already the case.

But if you coded something like this yourself now and ran a ROLLBACK
inside the loop, the holdable cursor would disappear (unless previously
committed), so you couldn't proceed with the loop.

The SQL standard for persistent stored modules explicitly prohibits
COMMIT and ROLLBACK in cursor loop bodies. But I think people will
eventually want it.

- COMMIT or ROLLBACK inside a procedure with a SET clause attached,

That also needs to be prohibited because of the way the GUC nesting
currently works. It's probably possible to fix it, but it would be a
separate effort.

and/or while SET LOCAL is in effect either at the inner or outer
level.

That seems to work fine.

These two are related -- if you don't permit anything that makes
temporary changes to GUCs at all, like SET clauses attached to
functions, then SET LOCAL won't cause any problems. The problem is if
you do a transaction operation when something set locally is in the
stack of values, but not at the top.

Yes, that's exactly the problem. So right now I'm just preventing the
problematic scenario. So fix that, one would possibly have to replace
the stack by something not quite a stack.

New patch attached.

In general this looks good. However, I'm getting runtime errors in
plperl_elog.c on two different Linux platforms (Fedora 25, Ubuntu
16.04). There seems to be something funky going on. And we do need to
work out why the commented out plperl test isn't working.

Detailed comments:

Referring to anonymous blocks might be a bit mystifying for some
readers, unless we note that they are invoked via DO.

I think this sentence should probably be worded a bit differently:

(And of course, BEGIN and END have different meanings in PL/pgSQL.)

Perhaps "Note that" instead of "And of course,".

Why aren't the SPI functions that error out or return 0 just void
instead of returning an int?

The docs say SPI_set_non_atomic() returns 0 on success, but the code
says otherwise.

This sentence in the comment in SPI_Commit() is slightly odd:

This restriction is particular to PLs implemented on top of SPI.

Perhaps "required by" rather than "particular to" would make it read better.

The empty free_commit() and free_rollback() functions in pl_funcs.c look
slightly odd. I realize that the compiler should optimize the calls
away, but it seems an odd style.

One other thing I wondered about was what if a PL function (say plperl)
used SPI to open an explicit cursor and then looped over it? If there
were a commit or rollback inside that loop we wouldn't have the same
protections we have in plpgsql, ISTM. I haven't tried this yet, so I'm
just speculating about what might happen.

cheers

andrew

--
Andrew Dunstan https://www.2ndQuadrant.com
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#33Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: Andrew Dunstan (#32)
Re: [HACKERS] Transaction control in procedures

On 12/7/17 18:47, Andrew Dunstan wrote:

Referring to anonymous blocks might be a bit mystifying for some
readers, unless we note that they are invoked via DO.

Added parenthetical comments.

I think this sentence should probably be worded a bit differently:

(And of course, BEGIN and END have different meanings in PL/pgSQL.)

Perhaps "Note that" instead of "And of course,".

fixed

Why aren't the SPI functions that error out or return 0 just void
instead of returning an int?

Tried to align then with existing functions, but I agree it seems weird.
Changed to return void.

The docs say SPI_set_non_atomic() returns 0 on success, but the code
says otherwise.

Fixed the documentation.

This sentence in the comment in SPI_Commit() is slightly odd:

This restriction is particular to PLs implemented on top of SPI.

Perhaps "required by" rather than "particular to" would make it read better.

fixed

The empty free_commit() and free_rollback() functions in pl_funcs.c look
slightly odd. I realize that the compiler should optimize the calls
away, but it seems an odd style.

That's how the existing code for other statements looks as well.

One other thing I wondered about was what if a PL function (say plperl)
used SPI to open an explicit cursor and then looped over it? If there
were a commit or rollback inside that loop we wouldn't have the same
protections we have in plpgsql, ISTM. I haven't tried this yet, so I'm
just speculating about what might happen.

Good point. I added test cases similar to the plpgsql tests to the
other three languages, which not-so-amusingly gave three different
outcomes. In PL/Perl in particular, the commit clears away the portal,
and the next call to spi_fetchrow() will then not find the cursor and
just return undefined. So that is not so nice. I'm thinking about
extending the portal pinning mechanism to the other languages as well,
which seems mildly useful independent of transaction management. I will
propose a patch for that soon.

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#34Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: Peter Eisentraut (#33)
1 attachment(s)
Re: [HACKERS] Transaction control in procedures

Updated patch attached.

I have addressed the most recent review comments I believe.

The question about what happens to cursor loops in PL/Perl and PL/Python
would be addressed by the separate thread "portal pinning". The test
cases in this patch are currently marked by FIXMEs.

I have changed the SPI API a bit. I got rid of SPI_set_nonatomic() and
instead introduced SPI_connect_ext() that you can pass flags to. The
advantage of that is that in the normal case we can continue to use the
existing memory contexts, so nothing changes for existing uses, which
seems desirable. (This also appears to address some sporadic test
failures in PL/Perl.)

I have also cleaned up the changes in portalmem.c further, so the
changes are now even smaller.

The commit message in this patch contains more details about some of
these changes.

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

Attachments:

v5-0001-Transaction-control-in-PL-procedures.patchtext/plain; charset=UTF-8; name=v5-0001-Transaction-control-in-PL-procedures.patch; x-mac-creator=0; x-mac-type=0Download
From 984d2974311ce6d8760ec3d59af66363cc53fc6d Mon Sep 17 00:00:00 2001
From: Peter Eisentraut <peter_e@gmx.net>
Date: Wed, 20 Dec 2017 09:25:45 -0500
Subject: [PATCH v5] Transaction control in PL procedures

In each of the supplied procedural languages (PL/pgSQL, PL/Perl,
PL/Python, PL/Tcl), add language-specific commit and rollback
functions/commands to control transactions in procedures in that
language.  Add similar underlying functions to SPI.  Some additional
cleanup so that transaction commit or abort doesn't blow away data
structures still used by the procedure call.  Add execution context
tracking to CALL and DO statements so that transaction control commands
can only be issued in top-level procedure and block calls, not function
calls or other procedure or block calls.

- SPI

Add a new function SPI_connect_ext() that is like SPI_connect() but
allows passing option flags.  The only option flag right now is
SPI_OPT_NONATOMIC.  A nonatomic SPI connection can execute transaction
control commands, otherwise it's not allowed.  This is meant to be
passed down from CALL and DO statements which themselves know in which
context they are called.  A nonatomic SPI connection uses different
memory management.  A normal SPI connection allocates its memory in
TopTransactionContext.  For nonatomic connections we use PortalContext
instead.  As the comment in SPI_connect_ext() (previously SPI_connect())
indicates, one could potentially use PortalContext in all cases, but it
seems safest to leave the existing uses alone, because this stuff is
complicated enough already.

SPI also gets new functions SPI_start_transaction(), SPI_commit(), and
SPI_rollback(), which can be used by PLs to implement their transaction
control logic.

- portalmem.c

Some adjustments were made in the code that cleans up portals at
transaction abort.  The portal code could already handle a command
*committing* a transaction and continuing (e.g., VACUUM), but it was not
quite prepared for a command *aborting* a transaction and continuing.

In AtAbort_Portals(), remove the code that marks an active portal as
failed.  As the comment there already predicted, this doesn't work if
the running command wants to keep running after transaction abort.  And
it's actually not necessary, because pquery.c is careful to run all
portal code in a PG_TRY block and explicitly runs MarkPortalFailed() if
there is an exception.  So the code in AtAbort_Portals() is never used
anyway.

In AtAbort_Portals() and AtCleanup_Portals(), we need to be careful not
to clean up active portals too much.  This mirrors similar code in
PreCommit_Portals().

- PL/Perl

Gets new functions spi_commit() and spi_rollback()

- PL/pgSQL

Gets new commands COMMIT and ROLLBACK.

Update the PL/SQL porting example in the documentation to reflect that
transactions are now possible in procedures.

- PL/Python

Gets new functions plpy.commit and plpy.rollback.

- PL/Tcl

Gets new commands commit and rollback.
---
 doc/src/sgml/plperl.sgml                           |  49 +++++
 doc/src/sgml/plpgsql.sgml                          |  91 ++++----
 doc/src/sgml/plpython.sgml                         |  39 ++++
 doc/src/sgml/pltcl.sgml                            |  41 ++++
 doc/src/sgml/ref/call.sgml                         |   7 +
 doc/src/sgml/ref/create_procedure.sgml             |   7 +
 doc/src/sgml/ref/do.sgml                           |   7 +
 doc/src/sgml/spi.sgml                              | 177 +++++++++++++++
 src/backend/commands/functioncmds.c                |  45 +++-
 src/backend/executor/spi.c                         |  99 ++++++++-
 src/backend/tcop/utility.c                         |   6 +-
 src/backend/utils/mmgr/portalmem.c                 |  49 +++--
 src/include/commands/defrem.h                      |   4 +-
 src/include/executor/spi.h                         |   7 +
 src/include/executor/spi_priv.h                    |   4 +
 src/include/nodes/nodes.h                          |   3 +-
 src/include/nodes/parsenodes.h                     |   7 +
 src/include/utils/portal.h                         |   1 +
 src/pl/plperl/GNUmakefile                          |   2 +-
 src/pl/plperl/SPI.xs                               |  10 +
 src/pl/plperl/expected/plperl_transaction.out      | 132 +++++++++++
 src/pl/plperl/plperl.c                             |  59 ++++-
 src/pl/plperl/plperl.h                             |   2 +
 src/pl/plperl/sql/plperl_transaction.sql           | 122 +++++++++++
 src/pl/plpgsql/src/Makefile                        |   2 +-
 .../plpgsql/src/expected/plpgsql_transaction.out   | 241 +++++++++++++++++++++
 src/pl/plpgsql/src/pl_exec.c                       |  66 +++++-
 src/pl/plpgsql/src/pl_funcs.c                      |  44 ++++
 src/pl/plpgsql/src/pl_gram.y                       |  34 +++
 src/pl/plpgsql/src/pl_handler.c                    |  11 +-
 src/pl/plpgsql/src/pl_scanner.c                    |   2 +
 src/pl/plpgsql/src/plpgsql.h                       |  22 +-
 src/pl/plpgsql/src/sql/plpgsql_transaction.sql     | 215 ++++++++++++++++++
 src/pl/plpython/Makefile                           |   1 +
 src/pl/plpython/expected/plpython_test.out         |   4 +-
 src/pl/plpython/expected/plpython_transaction.out  | 144 ++++++++++++
 src/pl/plpython/plpy_main.c                        |  11 +-
 src/pl/plpython/plpy_plpymodule.c                  |  39 ++++
 src/pl/plpython/sql/plpython_transaction.sql       | 117 ++++++++++
 src/pl/tcl/Makefile                                |   2 +-
 src/pl/tcl/expected/pltcl_transaction.out          | 100 +++++++++
 src/pl/tcl/pltcl.c                                 |  47 +++-
 src/pl/tcl/sql/pltcl_transaction.sql               |  98 +++++++++
 43 files changed, 2078 insertions(+), 92 deletions(-)
 create mode 100644 src/pl/plperl/expected/plperl_transaction.out
 create mode 100644 src/pl/plperl/sql/plperl_transaction.sql
 create mode 100644 src/pl/plpgsql/src/expected/plpgsql_transaction.out
 create mode 100644 src/pl/plpgsql/src/sql/plpgsql_transaction.sql
 create mode 100644 src/pl/plpython/expected/plpython_transaction.out
 create mode 100644 src/pl/plpython/sql/plpython_transaction.sql
 create mode 100644 src/pl/tcl/expected/pltcl_transaction.out
 create mode 100644 src/pl/tcl/sql/pltcl_transaction.sql

diff --git a/doc/src/sgml/plperl.sgml b/doc/src/sgml/plperl.sgml
index 100162dead..9acd41310f 100644
--- a/doc/src/sgml/plperl.sgml
+++ b/doc/src/sgml/plperl.sgml
@@ -661,6 +661,55 @@ <title>Database Access from PL/Perl</title>
     </para>
     </listitem>
     </varlistentry>
+
+    <varlistentry>
+     <term>
+      <literal><function>spi_commit()</function></literal>
+      <indexterm>
+       <primary>spi_commit</primary>
+       <secondary>in PL/Perl</secondary>
+     </indexterm>
+     </term>
+     <term>
+      <literal><function>spi_rollback()</function></literal>
+      <indexterm>
+       <primary>spi_rollback</primary>
+       <secondary>in PL/Perl</secondary>
+      </indexterm>
+     </term>
+     <listitem>
+      <para>
+       Commit or roll back the current transaction.  This can only be called
+       in a procedure or anonymous code block (<command>DO</command> command)
+       called from the top level.  (Note that it is not possible to run the
+       SQL commands <command>COMMIT</command> or <command>ROLLBACK</command>
+       via <function>spi_exec_query</function> or similar.  It has to be done
+       using these functions.)  After a transaction is ended, a new
+       transaction is automatically started, so there is no separate function
+       for that.
+      </para>
+
+      <para>
+       Here is an example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+CALL transaction_test1();
+</programlisting>
+      </para>
+     </listitem>
+    </varlistentry>
    </variablelist>
  </sect2>
 
diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml
index 7d23ed437e..00441af810 100644
--- a/doc/src/sgml/plpgsql.sgml
+++ b/doc/src/sgml/plpgsql.sgml
@@ -3449,6 +3449,48 @@ <title>Looping Through a Cursor's Result</title>
 
   </sect1>
 
+  <sect1 id="plpgsql-transactions">
+   <title>Transaction Management</title>
+
+   <para>
+    In procedures invoked by the <command>CALL</command> command from the top
+    level as well as in anonymous code blocks (<command>DO</command> command)
+    called from the top level, it is possible to end transactions using the
+    commands <command>COMMIT</command> and <command>ROLLBACK</command>.  A new
+    transaction is started automatically after a transaction is ended using
+    these commands, so there is no separate <command>START
+    TRANSACTION</command> command.  (Note that <command>BEGIN</command> and
+    <command>END</command> have different meanings in PL/pgSQL.)
+   </para>
+
+   <para>
+    Here is a simple example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+CALL transaction_test1();
+</programlisting>
+   </para>
+
+   <para>
+    Transactions cannot be ended inside loops through query results or inside
+    blocks with exception handlers.
+   </para>
+  </sect1>
+
   <sect1 id="plpgsql-errors-and-messages">
    <title>Errors and Messages</title>
 
@@ -5432,14 +5474,13 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
 <programlisting>
 CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id IN INTEGER) IS
     a_running_job_count INTEGER;
-    PRAGMA AUTONOMOUS_TRANSACTION; -- <co id="co.plpgsql-porting-pragma"/>
 BEGIN
-    LOCK TABLE cs_jobs IN EXCLUSIVE MODE; -- <co id="co.plpgsql-porting-locktable"/>
+    LOCK TABLE cs_jobs IN EXCLUSIVE MODE;
 
     SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL;
 
     IF a_running_job_count &gt; 0 THEN
-        COMMIT; -- free lock <co id="co.plpgsql-porting-commit"/>
+        COMMIT; -- free lock
         raise_application_error(-20000,
                  'Unable to create a new job: a job is currently running.');
     END IF;
@@ -5459,45 +5500,11 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
 </programlisting>
    </para>
 
-   <para>
-    Procedures like this can easily be converted into <productname>PostgreSQL</productname>
-    functions returning <type>void</type>. This procedure in
-    particular is interesting because it can teach us some things:
-
-    <calloutlist>
-     <callout arearefs="co.plpgsql-porting-pragma">
-      <para>
-       There is no <literal>PRAGMA</literal> statement in <productname>PostgreSQL</productname>.
-      </para>
-     </callout>
-
-     <callout arearefs="co.plpgsql-porting-locktable">
-      <para>
-       If you do a <command>LOCK TABLE</command> in <application>PL/pgSQL</application>,
-       the lock will not be released until the calling transaction is
-       finished.
-      </para>
-     </callout>
-
-     <callout arearefs="co.plpgsql-porting-commit">
-      <para>
-       You cannot issue <command>COMMIT</command> in a
-       <application>PL/pgSQL</application> function.  The function is
-       running within some outer transaction and so <command>COMMIT</command>
-       would imply terminating the function's execution.  However, in
-       this particular case it is not necessary anyway, because the lock
-       obtained by the <command>LOCK TABLE</command> will be released when
-       we raise an error.
-      </para>
-     </callout>
-    </calloutlist>
-   </para>
-
    <para>
     This is how we could port this procedure to <application>PL/pgSQL</application>:
 
 <programlisting>
-CREATE OR REPLACE FUNCTION cs_create_job(v_job_id integer) RETURNS void AS $$
+CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id integer) AS $$
 DECLARE
     a_running_job_count integer;
 BEGIN
@@ -5506,6 +5513,7 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
     SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL;
 
     IF a_running_job_count &gt; 0 THEN
+        COMMIT; -- free lock
         RAISE EXCEPTION 'Unable to create a new job: a job is currently running'; -- <co id="co.plpgsql-porting-raise"/>
     END IF;
 
@@ -5518,6 +5526,7 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
         WHEN unique_violation THEN -- <co id="co.plpgsql-porting-exception"/>
             -- don't worry if it already exists
     END;
+    COMMIT;
 END;
 $$ LANGUAGE plpgsql;
 </programlisting>
@@ -5541,12 +5550,6 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
       </para>
      </callout>
     </calloutlist>
-
-    The main functional difference between this procedure and the
-    Oracle equivalent is that the exclusive lock on the <literal>cs_jobs</literal>
-    table will be held until the calling transaction completes.  Also, if
-    the caller later aborts (for example due to an error), the effects of
-    this procedure will be rolled back.
    </para>
    </example>
   </sect2>
diff --git a/doc/src/sgml/plpython.sgml b/doc/src/sgml/plpython.sgml
index 0dbeee1fa2..8641038abe 100644
--- a/doc/src/sgml/plpython.sgml
+++ b/doc/src/sgml/plpython.sgml
@@ -1370,6 +1370,45 @@ <title>Older Python Versions</title>
   </sect2>
  </sect1>
 
+ <sect1 id="plpython-transactions">
+  <title>Transaction Management</title>
+
+  <para>
+   In a procedure called from the top level or an anonymous code block
+   (<command>DO</command> command) called from the top level it is possible to
+   control transactions.  To commit the current transaction, call
+   <literal>plpy.commit()</literal>.  To roll back the current transaction,
+   call <literal>plpy.rollback()</literal>.  (Note that it is not possible to
+   run the SQL commands <command>COMMIT</command> or
+   <command>ROLLBACK</command> via <function>plpy.execute</function> or
+   similar.  It has to be done using these functions.)  After a transaction is
+   ended, a new transaction is automatically started, so there is no separate
+   function for that.
+  </para>
+
+  <para>
+   Here is an example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+CALL transaction_test1();
+</programlisting>
+  </para>
+
+  <para>
+   Transactions cannot be ended when an explicit subtransaction is active.
+  </para>
+ </sect1>
+
  <sect1 id="plpython-util">
   <title>Utility Functions</title>
   <para>
diff --git a/doc/src/sgml/pltcl.sgml b/doc/src/sgml/pltcl.sgml
index 8018783b0a..a834ab8862 100644
--- a/doc/src/sgml/pltcl.sgml
+++ b/doc/src/sgml/pltcl.sgml
@@ -1002,6 +1002,47 @@ <title>Explicit Subtransactions in PL/Tcl</title>
     </para>
    </sect1>
 
+   <sect1 id="pltcl-transactions">
+    <title>Transaction Management</title>
+
+    <para>
+     In a procedure called from the top level or an anonymous code block
+     (<command>DO</command> command) called from the top level it is possible
+     to control transactions.  To commit the current transaction, call the
+     <literal>commit</literal> command.  To roll back the current transaction,
+     call the <literal>rollback</literal> command.  (Note that it is not
+     possible to run the SQL commands <command>COMMIT</command> or
+     <command>ROLLBACK</command> via <function>spi_exec</function> or similar.
+     It has to be done using these functions.)  After a transaction is ended,
+     a new transaction is automatically started, so there is no separate
+     command for that.
+    </para>
+
+    <para>
+     Here is an example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i &lt; 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+
+CALL transaction_test1();
+</programlisting>
+    </para>
+
+    <para>
+     Transactions cannot be ended when an explicit subtransaction is active.
+    </para>
+   </sect1>
+
    <sect1 id="pltcl-config">
     <title>PL/Tcl Configuration</title>
 
diff --git a/doc/src/sgml/ref/call.sgml b/doc/src/sgml/ref/call.sgml
index 2741d8d15e..03da4518ee 100644
--- a/doc/src/sgml/ref/call.sgml
+++ b/doc/src/sgml/ref/call.sgml
@@ -70,6 +70,13 @@ <title>Notes</title>
   <para>
    To call a function (not a procedure), use <command>SELECT</command> instead.
   </para>
+
+  <para>
+   If <command>CALL</command> is executed in a transaction block, then the
+   called procedure cannot execute transaction control statements.
+   Transaction control statements are only allowed if <command>CALL</command>
+   is executed in its own transaction.
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_procedure.sgml b/doc/src/sgml/ref/create_procedure.sgml
index d712043824..bbf8b03d04 100644
--- a/doc/src/sgml/ref/create_procedure.sgml
+++ b/doc/src/sgml/ref/create_procedure.sgml
@@ -228,6 +228,13 @@ <title>Parameters</title>
        procedure exit, unless the current transaction is rolled back.
       </para>
 
+      <para>
+       If a <literal>SET</literal> clause is attached to a procedure, then
+       that procedure cannot execute transaction control statements (for
+       example, <command>COMMIT</command> and <command>ROLLBACK</command>,
+       depending on the language).
+      </para>
+
       <para>
        See <xref linkend="sql-set"/> and
        <xref linkend="runtime-config"/>
diff --git a/doc/src/sgml/ref/do.sgml b/doc/src/sgml/ref/do.sgml
index 061218b135..b9a6f9a6fd 100644
--- a/doc/src/sgml/ref/do.sgml
+++ b/doc/src/sgml/ref/do.sgml
@@ -91,6 +91,13 @@ <title>Notes</title>
    This is the same privilege requirement as for creating a function
    in the language.
   </para>
+
+  <para>
+   If <command>DO</command> is executed in a transaction block, then the
+   procedure code cannot execute transaction control statements.  Transaction
+   control statements are only allowed if <command>DO</command> is executed in
+   its own transaction.
+  </para>
  </refsect1>
 
  <refsect1 id="sql-do-examples">
diff --git a/doc/src/sgml/spi.sgml b/doc/src/sgml/spi.sgml
index 350f0863e9..10448922b1 100644
--- a/doc/src/sgml/spi.sgml
+++ b/doc/src/sgml/spi.sgml
@@ -64,6 +64,7 @@ <title>Interface Functions</title>
 
  <refentry id="spi-spi-connect">
   <indexterm><primary>SPI_connect</primary></indexterm>
+  <indexterm><primary>SPI_connect_ext</primary></indexterm>
 
   <refmeta>
    <refentrytitle>SPI_connect</refentrytitle>
@@ -72,12 +73,17 @@ <title>Interface Functions</title>
 
   <refnamediv>
    <refname>SPI_connect</refname>
+   <refname>SPI_connect_ext</refname>
    <refpurpose>connect a procedure to the SPI manager</refpurpose>
  </refnamediv>
 
  <refsynopsisdiv>
 <synopsis>
 int SPI_connect(void)
+</synopsis>
+
+ <synopsis>
+int SPI_connect_ext(int <parameter>options</parameter>)
 </synopsis>
  </refsynopsisdiv>
 
@@ -90,6 +96,31 @@ <title>Description</title>
    function if you want to execute commands through SPI.  Some utility
    SPI functions can be called from unconnected procedures.
   </para>
+
+  <para>
+   <function>SPI_connect_ext</function> does the same but has an argument that
+   allows passing option flags.  Currently, the following option values are
+   available:
+   <variablelist>
+    <varlistentry>
+     <term><symbol>SPI_OPT_NONATOMIC</symbol></term>
+     <listitem>
+      <para>
+       Sets the SPI connection to be <firstterm>nonatomic</firstterm>, which
+       means that transaction control calls <function>SPI_commit</function>,
+       <function>SPI_rollback</function>, and
+       <function>SPI_start_transaction</function> are allowed.  Otherwise,
+       calling these functions will result in an immediate error.
+      </para>
+     </listitem>
+    </varlistentry>
+   </variablelist>
+  </para>
+
+  <para>
+   <literal>SPI_connect()</literal> is equivalent to
+   <literal>SPI_connect_ext(0)</literal>.
+  </para>
  </refsect1>
 
  <refsect1>
@@ -4325,6 +4356,152 @@ <title>Return Value</title>
 
  </sect1>
 
+ <sect1 id="spi-transaction">
+  <title>Transaction Management</title>
+
+  <para>
+   It is not possible to run transaction control commands such
+   as <command>COMMIT</command> and <command>ROLLBACK</command> through SPI
+   functions such as <function>SPI_execute</function>.  There are, however,
+   separate interface functions that allow transaction control through SPI.
+  </para>
+
+  <para>
+   It is not generally safe and sensible to start and end transactions in
+   arbitrary user-defined SQL-callable functions without taking into account
+   the context in which they are called.  For example, a transaction boundary
+   in the middle of a function that is part of a complex SQL expression that
+   is part of some SQL command will probably result in obscure internal errors
+   or crashes.  The interface functions presented here are primarily intended
+   to be used by procedural language implementations to support transaction
+   management in procedures that are invoked by the <command>CALL</command>
+   command, taking the context of the <command>CALL</command> invocation into
+   account.  SPI procedures implemented in C can implement the same logic, but
+   the details of that are beyond the scope of this documentation.
+  </para>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-commit">
+ <indexterm><primary>SPI_commit</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_commit</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_commit</refname>
+  <refpurpose>commit the current transaction</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+void SPI_commit(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_commit</function> commits the current transaction.  It is
+   approximately equivalent to running the SQL
+   command <command>COMMIT</command>.  After a transaction is committed, a new
+   transaction has to be started
+   using <function>SPI_start_transaction</function> before further database
+   actions can be executed.
+  </para>
+
+  <para>
+   This function can only be executed if the SPI connection has been set as
+   nonatomic in the call to <function>SPI_connect_ext</function>.
+  </para>
+ </refsect1>
+</refentry>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-rollback">
+ <indexterm><primary>SPI_rollback</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_rollback</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_rollback</refname>
+  <refpurpose>abort the current transaction</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+void SPI_rollback(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_rollback</function> rolls back the current transaction.  It
+   is approximately equivalent to running the SQL
+   command <command>ROLLBACK</command>.  After a transaction is rolled back, a
+   new transaction has to be started
+   using <function>SPI_start_transaction</function> before further database
+   actions can be executed.
+  </para>
+
+  <para>
+   This function can only be executed if the SPI connection has been set as
+   nonatomic in the call to <function>SPI_connect_ext</function>.
+  </para>
+ </refsect1>
+</refentry>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-start-transaction">
+ <indexterm><primary>SPI_start_transaction</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_start_transaction</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_start_transaction</refname>
+  <refpurpose>start a new transaction</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+void SPI_start_transaction(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_start_transaction</function> starts a new transaction.  It
+   can only be called after <function>SPI_commit</function>
+   or <function>SPI_rollback</function>, as there is no transaction active at
+   that point.  Normally, when an SPI procedure is called, there is already a
+   transaction active, so attempting to start another one before closing out
+   the current one will result in an error.
+  </para>
+
+  <para>
+   This function can only be executed if the SPI connection has been set as
+   nonatomic in the call to <function>SPI_connect_ext</function>.
+  </para>
+ </refsect1>
+</refentry>
+
+ </sect1>
+
  <sect1 id="spi-visibility">
   <title>Visibility of Data Changes</title>
 
diff --git a/src/backend/commands/functioncmds.c b/src/backend/commands/functioncmds.c
index 2a9c90133d..4101817c5e 100644
--- a/src/backend/commands/functioncmds.c
+++ b/src/backend/commands/functioncmds.c
@@ -65,6 +65,7 @@
 #include "utils/fmgroids.h"
 #include "utils/guc.h"
 #include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/rel.h"
 #include "utils/syscache.h"
 #include "utils/tqual.h"
@@ -2138,7 +2139,7 @@ IsThereFunctionInNamespace(const char *proname, int pronargs,
  *		Execute inline procedural-language code
  */
 void
-ExecuteDoStmt(DoStmt *stmt)
+ExecuteDoStmt(DoStmt *stmt, bool atomic)
 {
 	InlineCodeBlock *codeblock = makeNode(InlineCodeBlock);
 	ListCell   *arg;
@@ -2200,6 +2201,7 @@ ExecuteDoStmt(DoStmt *stmt)
 	codeblock->langOid = HeapTupleGetOid(languageTuple);
 	languageStruct = (Form_pg_language) GETSTRUCT(languageTuple);
 	codeblock->langIsTrusted = languageStruct->lanpltrusted;
+	codeblock->atomic = atomic;
 
 	if (languageStruct->lanpltrusted)
 	{
@@ -2236,9 +2238,28 @@ ExecuteDoStmt(DoStmt *stmt)
 
 /*
  * Execute CALL statement
+ *
+ * Inside a top-level CALL statement, transaction-terminating commands such as
+ * COMMIT or a PL-specific equivalent are allowed.  The terminology in the SQL
+ * standard is that CALL establishes a non-atomic execution context.  Most
+ * other commands establish an atomic execution context, in which transaction
+ * control actions are not allowed.  If there are nested executions of CALL,
+ * we want to track the execution context recursively, so that the nested
+ * CALLs can also do transaction control.  Note, however, that for example in
+ * CALL -> SELECT -> CALL, the second call cannot do transaction control,
+ * because the SELECT in between establishes an atomic execution context.
+ *
+ * So when ExecuteCallStmt() is called from the top level, we pass in atomic =
+ * false (recall that that means transactions = yes).  We then create a
+ * CallContext node with content atomic = false, which is passed in the
+ * fcinfo->context field to the procedure invocation.  The language
+ * implementation should then take appropriate measures to allow or prevent
+ * transaction commands based on that information, e.g., call
+ * SPI_set_nonatomic().  The language should also pass on the atomic flag to
+ * any recursive invocations to CALL.
  */
 void
-ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
+ExecuteCallStmt(ParseState *pstate, CallStmt *stmt, bool atomic)
 {
 	List	   *targs;
 	ListCell   *lc;
@@ -2249,6 +2270,8 @@ ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
 	AclResult   aclresult;
 	FmgrInfo	flinfo;
 	FunctionCallInfoData fcinfo;
+	CallContext *callcontext;
+	HeapTuple	tp;
 
 	targs = NIL;
 	foreach(lc, stmt->funccall->args)
@@ -2284,8 +2307,24 @@ ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
 							   FUNC_MAX_ARGS,
 							   FUNC_MAX_ARGS)));
 
+	callcontext = makeNode(CallContext);
+	callcontext->atomic = atomic;
+
+	/*
+	 * If proconfig is set we can't allow transaction commands because of the
+	 * way the GUC stacking works: The transaction boundary would have to pop
+	 * the proconfig setting off the stack.  That restriction could be lifted
+	 * by redesigning the GUC nesting mechanism a bit.
+	 */
+	tp = SearchSysCache1(PROCOID, ObjectIdGetDatum(fexpr->funcid));
+	if (!HeapTupleIsValid(tp))
+		elog(ERROR, "cache lookup failed for function %u", fexpr->funcid);
+	if (!heap_attisnull(tp, Anum_pg_proc_proconfig))
+		callcontext->atomic = true;
+	ReleaseSysCache(tp);
+
 	fmgr_info(fexpr->funcid, &flinfo);
-	InitFunctionCallInfoData(fcinfo, &flinfo, nargs, fexpr->inputcollid, NULL, NULL);
+	InitFunctionCallInfoData(fcinfo, &flinfo, nargs, fexpr->inputcollid, (Node *) callcontext, NULL);
 
 	i = 0;
 	foreach (lc, fexpr->args)
diff --git a/src/backend/executor/spi.c b/src/backend/executor/spi.c
index f3da2ddd08..c3d1f59010 100644
--- a/src/backend/executor/spi.c
+++ b/src/backend/executor/spi.c
@@ -82,6 +82,12 @@ static bool _SPI_checktuples(void);
 
 int
 SPI_connect(void)
+{
+	return SPI_connect_ext(0);
+}
+
+int
+SPI_connect_ext(int options)
 {
 	int			newdepth;
 
@@ -92,7 +98,7 @@ SPI_connect(void)
 			elog(ERROR, "SPI stack corrupted");
 		newdepth = 16;
 		_SPI_stack = (_SPI_connection *)
-			MemoryContextAlloc(TopTransactionContext,
+			MemoryContextAlloc(TopMemoryContext,
 							   newdepth * sizeof(_SPI_connection));
 		_SPI_stack_depth = newdepth;
 	}
@@ -124,19 +130,25 @@ SPI_connect(void)
 	_SPI_current->execCxt = NULL;
 	_SPI_current->connectSubid = GetCurrentSubTransactionId();
 	_SPI_current->queryEnv = NULL;
+	_SPI_current->atomic = (options & SPI_OPT_NONATOMIC ? false : true);
+	_SPI_current->internal_xact = false;
 
 	/*
 	 * Create memory contexts for this procedure
 	 *
-	 * XXX it would be better to use PortalContext as the parent context, but
-	 * we may not be inside a portal (consider deferred-trigger execution).
-	 * Perhaps CurTransactionContext would do?	For now it doesn't matter
-	 * because we clean up explicitly in AtEOSubXact_SPI().
+	 * In atomic contexts (the normal case), we use TopTransactionContext,
+	 * otherwise PortalContext, so that it lives across transaction
+	 * boundaries.
+	 *
+	 * XXX It could be better to use PortalContext as the parent context in
+	 * all cases, but we may not be inside a portal (consider deferred-trigger
+	 * execution).  Perhaps CurTransactionContext could be an option?  For now
+	 * it doesn't matter because we clean up explicitly in AtEOSubXact_SPI().
 	 */
-	_SPI_current->procCxt = AllocSetContextCreate(TopTransactionContext,
+	_SPI_current->procCxt = AllocSetContextCreate(_SPI_current->atomic ? TopTransactionContext : PortalContext,
 												  "SPI Proc",
 												  ALLOCSET_DEFAULT_SIZES);
-	_SPI_current->execCxt = AllocSetContextCreate(TopTransactionContext,
+	_SPI_current->execCxt = AllocSetContextCreate(_SPI_current->atomic ? TopTransactionContext : _SPI_current->procCxt,
 												  "SPI Exec",
 												  ALLOCSET_DEFAULT_SIZES);
 	/* ... and switch to procedure's context */
@@ -181,12 +193,82 @@ SPI_finish(void)
 	return SPI_OK_FINISH;
 }
 
+void
+SPI_start_transaction(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	StartTransactionCommand();
+	MemoryContextSwitchTo(oldcontext);
+}
+
+void
+SPI_commit(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	if (_SPI_current->atomic)
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("invalid transaction termination")));
+
+	/*
+	 * This restriction is required by PLs implemented on top of SPI.  They
+	 * use subtransactions to establish exception blocks that are supposed to
+	 * be rolled back together if there is an error.  Terminating the
+	 * top-level transaction in such a block violates that idea.  A future PL
+	 * implementation might have different ideas about this, in which case
+	 * this restriction would have to be refined or the check possibly be
+	 * moved out of SPI into the PLs.
+	 */
+	if (IsSubTransaction())
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("cannot commit while a subtransaction is active")));
+
+	_SPI_current->internal_xact = true;
+
+	if (ActiveSnapshotSet())
+		PopActiveSnapshot();
+	CommitTransactionCommand();
+	MemoryContextSwitchTo(oldcontext);
+
+	_SPI_current->internal_xact = false;
+}
+
+void
+SPI_rollback(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	if (_SPI_current->atomic)
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("invalid transaction termination")));
+
+	/* see under SPI_commit() */
+	if (IsSubTransaction())
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("cannot roll back while a subtransaction is active")));
+
+	_SPI_current->internal_xact = true;
+
+	AbortCurrentTransaction();
+	MemoryContextSwitchTo(oldcontext);
+
+	_SPI_current->internal_xact = false;
+}
+
 /*
  * Clean up SPI state at transaction commit or abort.
  */
 void
 AtEOXact_SPI(bool isCommit)
 {
+	if (_SPI_current && _SPI_current->internal_xact)
+		return;
+
 	/*
 	 * Note that memory contexts belonging to SPI stack entries will be freed
 	 * automatically, so we can ignore them here.  We just need to restore our
@@ -224,6 +306,9 @@ AtEOSubXact_SPI(bool isCommit, SubTransactionId mySubid)
 		if (connection->connectSubid != mySubid)
 			break;				/* couldn't be any underneath it either */
 
+		if (connection->internal_xact)
+			break;
+
 		found = true;
 
 		/*
diff --git a/src/backend/tcop/utility.c b/src/backend/tcop/utility.c
index 4da1f8f643..35f018c8da 100644
--- a/src/backend/tcop/utility.c
+++ b/src/backend/tcop/utility.c
@@ -529,7 +529,8 @@ standard_ProcessUtility(PlannedStmt *pstmt,
 			break;
 
 		case T_DoStmt:
-			ExecuteDoStmt((DoStmt *) parsetree);
+			ExecuteDoStmt((DoStmt *) parsetree,
+						  (context != PROCESS_UTILITY_TOPLEVEL || IsTransactionBlock()));
 			break;
 
 		case T_CreateTableSpaceStmt:
@@ -658,7 +659,8 @@ standard_ProcessUtility(PlannedStmt *pstmt,
 			break;
 
 		case T_CallStmt:
-			ExecuteCallStmt(pstate, castNode(CallStmt, parsetree));
+			ExecuteCallStmt(pstate, castNode(CallStmt, parsetree),
+							(context != PROCESS_UTILITY_TOPLEVEL || IsTransactionBlock()));
 			break;
 
 		case T_ClusterStmt:
diff --git a/src/backend/utils/mmgr/portalmem.c b/src/backend/utils/mmgr/portalmem.c
index d03b779407..a78e51c9d4 100644
--- a/src/backend/utils/mmgr/portalmem.c
+++ b/src/backend/utils/mmgr/portalmem.c
@@ -736,11 +736,8 @@ PreCommit_Portals(bool isPrepare)
 /*
  * Abort processing for portals.
  *
- * At this point we reset "active" status and run the cleanup hook if
- * present, but we can't release the portal's memory until the cleanup call.
- *
- * The reason we need to reset active is so that we can replace the unnamed
- * portal, else we'll fail to execute ROLLBACK when it arrives.
+ * At this point we run the cleanup hook if present, but we can't release the
+ * portal's memory until the cleanup call.
  */
 void
 AtAbort_Portals(void)
@@ -754,17 +751,6 @@ AtAbort_Portals(void)
 	{
 		Portal		portal = hentry->portal;
 
-		/*
-		 * See similar code in AtSubAbort_Portals().  This would fire if code
-		 * orchestrating multiple top-level transactions within a portal, such
-		 * as VACUUM, caught errors and continued under the same portal with a
-		 * fresh transaction.  No part of core PostgreSQL functions that way.
-		 * XXX Such code would wish the portal to remain ACTIVE, as in
-		 * PreCommit_Portals().
-		 */
-		if (portal->status == PORTAL_ACTIVE)
-			MarkPortalFailed(portal);
-
 		/*
 		 * Do nothing else to cursors held over from a previous transaction.
 		 */
@@ -804,9 +790,10 @@ AtAbort_Portals(void)
 		 * Although we can't delete the portal data structure proper, we can
 		 * release any memory in subsidiary contexts, such as executor state.
 		 * The cleanup hook was the last thing that might have needed data
-		 * there.
+		 * there.  But leave active portals alone.
 		 */
-		MemoryContextDeleteChildren(PortalGetHeapMemory(portal));
+		if (portal->status != PORTAL_ACTIVE)
+			MemoryContextDeleteChildren(PortalGetHeapMemory(portal));
 	}
 }
 
@@ -826,6 +813,13 @@ AtCleanup_Portals(void)
 	{
 		Portal		portal = hentry->portal;
 
+		/*
+		 * Do not touch active portals --- this can only happen in the case of
+		 * a multi-transaction command.
+		 */
+		if (portal->status == PORTAL_ACTIVE)
+			continue;
+
 		/* Do nothing to cursors held over from a previous transaction */
 		if (portal->createSubid == InvalidSubTransactionId)
 		{
@@ -1155,3 +1149,22 @@ ThereAreNoReadyPortals(void)
 
 	return true;
 }
+
+bool
+ThereArePinnedPortals(void)
+{
+	HASH_SEQ_STATUS status;
+	PortalHashEnt *hentry;
+
+	hash_seq_init(&status, PortalHashTable);
+
+	while ((hentry = (PortalHashEnt *) hash_seq_search(&status)) != NULL)
+	{
+		Portal		portal = hentry->portal;
+
+		if (portal->portalPinned)
+			return true;
+	}
+
+	return false;
+}
diff --git a/src/include/commands/defrem.h b/src/include/commands/defrem.h
index 52cbf61ccb..b03f5b6a95 100644
--- a/src/include/commands/defrem.h
+++ b/src/include/commands/defrem.h
@@ -58,8 +58,8 @@ extern ObjectAddress CreateTransform(CreateTransformStmt *stmt);
 extern void DropTransformById(Oid transformOid);
 extern void IsThereFunctionInNamespace(const char *proname, int pronargs,
 						   oidvector *proargtypes, Oid nspOid);
-extern void ExecuteDoStmt(DoStmt *stmt);
-extern void ExecuteCallStmt(ParseState *pstate, CallStmt *stmt);
+extern void ExecuteDoStmt(DoStmt *stmt, bool atomic);
+extern void ExecuteCallStmt(ParseState *pstate, CallStmt *stmt, bool atomic);
 extern Oid	get_cast_oid(Oid sourcetypeid, Oid targettypeid, bool missing_ok);
 extern Oid	get_transform_oid(Oid type_id, Oid lang_id, bool missing_ok);
 extern void interpret_function_parameter_list(ParseState *pstate,
diff --git a/src/include/executor/spi.h b/src/include/executor/spi.h
index acade7e92e..9c35e0f335 100644
--- a/src/include/executor/spi.h
+++ b/src/include/executor/spi.h
@@ -65,6 +65,8 @@ typedef struct _SPI_plan *SPIPlanPtr;
 #define SPI_OK_REL_UNREGISTER	16
 #define SPI_OK_TD_REGISTER		17
 
+#define SPI_OPT_NONATOMIC		(1 << 0)
+
 /* These used to be functions, now just no-ops for backwards compatibility */
 #define SPI_push()	((void) 0)
 #define SPI_pop()	((void) 0)
@@ -78,6 +80,7 @@ extern PGDLLIMPORT SPITupleTable *SPI_tuptable;
 extern PGDLLIMPORT int SPI_result;
 
 extern int	SPI_connect(void);
+extern int	SPI_connect_ext(int options);
 extern int	SPI_finish(void);
 extern int	SPI_execute(const char *src, bool read_only, long tcount);
 extern int SPI_execute_plan(SPIPlanPtr plan, Datum *Values, const char *Nulls,
@@ -156,6 +159,10 @@ extern int	SPI_register_relation(EphemeralNamedRelation enr);
 extern int	SPI_unregister_relation(const char *name);
 extern int	SPI_register_trigger_data(TriggerData *tdata);
 
+extern void SPI_start_transaction(void);
+extern void SPI_commit(void);
+extern void SPI_rollback(void);
+
 extern void AtEOXact_SPI(bool isCommit);
 extern void AtEOSubXact_SPI(bool isCommit, SubTransactionId mySubid);
 
diff --git a/src/include/executor/spi_priv.h b/src/include/executor/spi_priv.h
index 8fae755418..9dc8af22e4 100644
--- a/src/include/executor/spi_priv.h
+++ b/src/include/executor/spi_priv.h
@@ -36,6 +36,10 @@ typedef struct
 	MemoryContext savedcxt;		/* context of SPI_connect's caller */
 	SubTransactionId connectSubid;	/* ID of connecting subtransaction */
 	QueryEnvironment *queryEnv; /* query environment setup for SPI level */
+
+	/* transaction management support */
+	bool		atomic;			/* atomic execution context, does not allow transactions */
+	bool		internal_xact;	/* SPI-managed transaction boundary, skip cleanup */
 } _SPI_connection;
 
 /*
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index c5b5115f5b..6dcd51e958 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -500,7 +500,8 @@ typedef enum NodeTag
 	T_FdwRoutine,				/* in foreign/fdwapi.h */
 	T_IndexAmRoutine,			/* in access/amapi.h */
 	T_TsmRoutine,				/* in access/tsmapi.h */
-	T_ForeignKeyCacheInfo		/* in utils/rel.h */
+	T_ForeignKeyCacheInfo,		/* in utils/rel.h */
+	T_CallContext				/* in nodes/parsenodes.h */
 } NodeTag;
 
 /*
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index 2eaa6b2774..cb1afd68f8 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2803,6 +2803,7 @@ typedef struct InlineCodeBlock
 	char	   *source_text;	/* source text of anonymous code block */
 	Oid			langOid;		/* OID of selected language */
 	bool		langIsTrusted;	/* trusted property of the language */
+	bool		atomic;			/* atomic execution context */
 } InlineCodeBlock;
 
 /* ----------------------
@@ -2815,6 +2816,12 @@ typedef struct CallStmt
 	FuncCall   *funccall;
 } CallStmt;
 
+typedef struct CallContext
+{
+	NodeTag		type;
+	bool		atomic;
+} CallContext;
+
 /* ----------------------
  *		Alter Object Rename Statement
  * ----------------------
diff --git a/src/include/utils/portal.h b/src/include/utils/portal.h
index cb6f00081d..cdbe7323d8 100644
--- a/src/include/utils/portal.h
+++ b/src/include/utils/portal.h
@@ -237,5 +237,6 @@ extern PlannedStmt *PortalGetPrimaryStmt(Portal portal);
 extern void PortalCreateHoldStore(Portal portal);
 extern void PortalHashTableDeleteAll(void);
 extern bool ThereAreNoReadyPortals(void);
+extern bool ThereArePinnedPortals(void);
 
 #endif							/* PORTAL_H */
diff --git a/src/pl/plperl/GNUmakefile b/src/pl/plperl/GNUmakefile
index b829027d05..933abb47c4 100644
--- a/src/pl/plperl/GNUmakefile
+++ b/src/pl/plperl/GNUmakefile
@@ -55,7 +55,7 @@ endif # win32
 SHLIB_LINK = $(perl_embed_ldflags)
 
 REGRESS_OPTS = --dbname=$(PL_TESTDB) --load-extension=plperl  --load-extension=plperlu
-REGRESS = plperl plperl_lc plperl_trigger plperl_shared plperl_elog plperl_util plperl_init plperlu plperl_array plperl_call
+REGRESS = plperl plperl_lc plperl_trigger plperl_shared plperl_elog plperl_util plperl_init plperlu plperl_array plperl_call plperl_transaction
 # if Perl can support two interpreters in one backend,
 # test plperl-and-plperlu cases
 ifneq ($(PERL),)
diff --git a/src/pl/plperl/SPI.xs b/src/pl/plperl/SPI.xs
index d9e6f579d4..de5d812cbd 100644
--- a/src/pl/plperl/SPI.xs
+++ b/src/pl/plperl/SPI.xs
@@ -17,6 +17,7 @@
 #define PG_NEED_PERL_XSUB_H
 #include "plperl.h"
 #include "plperl_helpers.h"
+#include "executor/spi.h"
 
 
 MODULE = PostgreSQL::InServer::SPI PREFIX = spi_
@@ -152,6 +153,15 @@ spi_spi_cursor_close(sv)
 		plperl_spi_cursor_close(cursor);
 		pfree(cursor);
 
+void
+spi_spi_commit()
+	CODE:
+		plperl_spi_commit();
+
+void
+spi_spi_rollback()
+	CODE:
+		plperl_spi_rollback();
 
 BOOT:
     items = 0;  /* avoid 'unused variable' warning */
diff --git a/src/pl/plperl/expected/plperl_transaction.out b/src/pl/plperl/expected/plperl_transaction.out
new file mode 100644
index 0000000000..5ce33d9c7c
--- /dev/null
+++ b/src/pl/plperl/expected/plperl_transaction.out
@@ -0,0 +1,132 @@
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+DO
+LANGUAGE plperl
+$$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+return 1;
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination at line 5.
+CONTEXT:  PL/Perl function "transaction_test2"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query("CALL transaction_test1()");
+return 1;
+$$;
+SELECT transaction_test3();
+ERROR:  invalid transaction termination at line 5. at line 2.
+CONTEXT:  PL/Perl function "transaction_test3"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query('DO LANGUAGE plperl $x$ spi_commit(); $x$');
+return 1;
+$$;
+SELECT transaction_test4();
+ERROR:  invalid transaction termination at line 1. at line 2.
+CONTEXT:  PL/Perl function "transaction_test4"
+-- FIXME
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+TRUNCATE test1;
+DO LANGUAGE plperl $$
+my $sth = spi_query("SELECT * FROM test2 ORDER BY x");
+my $row;
+while (defined($row = spi_fetchrow($sth))) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES (" . $row->{x} . ")");
+    spi_commit();
+}
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+(1 row)
+
+-- FIXME
+-- rollback inside cursor loop
+TRUNCATE test1;
+DO LANGUAGE plperl $$
+my $sth = spi_query("SELECT * FROM test2 ORDER BY x");
+my $row;
+while (defined($row = spi_fetchrow($sth))) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES (" . $row->{x} . ")");
+    spi_rollback();
+}
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+DROP TABLE test1;
+DROP TABLE test2;
diff --git a/src/pl/plperl/plperl.c b/src/pl/plperl/plperl.c
index 41fd0ba421..b3f3b43f8d 100644
--- a/src/pl/plperl/plperl.c
+++ b/src/pl/plperl/plperl.c
@@ -1929,7 +1929,7 @@ plperl_inline_handler(PG_FUNCTION_ARGS)
 
 		current_call_data = &this_call_data;
 
-		if (SPI_connect() != SPI_OK_CONNECT)
+		if (SPI_connect_ext(codeblock->atomic ? 0 : SPI_OPT_NONATOMIC) != SPI_OK_CONNECT)
 			elog(ERROR, "could not connect to SPI manager");
 
 		select_perl_context(desc.lanpltrusted);
@@ -2396,13 +2396,18 @@ plperl_call_perl_event_trigger_func(plperl_proc_desc *desc,
 static Datum
 plperl_func_handler(PG_FUNCTION_ARGS)
 {
+	bool		nonatomic;
 	plperl_proc_desc *prodesc;
 	SV		   *perlret;
 	Datum		retval = 0;
 	ReturnSetInfo *rsi;
 	ErrorContextCallback pl_error_context;
 
-	if (SPI_connect() != SPI_OK_CONNECT)
+	nonatomic = fcinfo->context &&
+		IsA(fcinfo->context, CallContext) &&
+		!castNode(CallContext, fcinfo->context)->atomic;
+
+	if (SPI_connect_ext(nonatomic ? SPI_OPT_NONATOMIC : 0) != SPI_OK_CONNECT)
 		elog(ERROR, "could not connect to SPI manager");
 
 	prodesc = compile_plperl_function(fcinfo->flinfo->fn_oid, false, false);
@@ -3945,6 +3950,56 @@ plperl_spi_freeplan(char *query)
 	SPI_freeplan(plan);
 }
 
+void
+plperl_spi_commit(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	PG_TRY();
+	{
+		SPI_commit();
+		SPI_start_transaction();
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Punt the error to Perl */
+		croak_cstr(edata->message);
+	}
+	PG_END_TRY();
+}
+
+void
+plperl_spi_rollback(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	PG_TRY();
+	{
+		SPI_rollback();
+		SPI_start_transaction();
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Punt the error to Perl */
+		croak_cstr(edata->message);
+	}
+	PG_END_TRY();
+}
+
 /*
  * Implementation of plperl's elog() function
  *
diff --git a/src/pl/plperl/plperl.h b/src/pl/plperl/plperl.h
index aac95f8d2c..dca34d5dbc 100644
--- a/src/pl/plperl/plperl.h
+++ b/src/pl/plperl/plperl.h
@@ -125,6 +125,8 @@ HV		   *plperl_spi_exec_prepared(char *, HV *, int, SV **);
 SV		   *plperl_spi_query_prepared(char *, int, SV **);
 void		plperl_spi_freeplan(char *);
 void		plperl_spi_cursor_close(char *);
+void		plperl_spi_commit(void);
+void		plperl_spi_rollback(void);
 char	   *plperl_sv_to_literal(SV *, char *);
 void		plperl_util_elog(int level, SV *msg);
 
diff --git a/src/pl/plperl/sql/plperl_transaction.sql b/src/pl/plperl/sql/plperl_transaction.sql
new file mode 100644
index 0000000000..081e03f238
--- /dev/null
+++ b/src/pl/plperl/sql/plperl_transaction.sql
@@ -0,0 +1,122 @@
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+DO
+LANGUAGE plperl
+$$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+return 1;
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query("CALL transaction_test1()");
+return 1;
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query('DO LANGUAGE plperl $x$ spi_commit(); $x$');
+return 1;
+$$;
+
+SELECT transaction_test4();
+
+
+-- FIXME
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+
+TRUNCATE test1;
+
+DO LANGUAGE plperl $$
+my $sth = spi_query("SELECT * FROM test2 ORDER BY x");
+my $row;
+while (defined($row = spi_fetchrow($sth))) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES (" . $row->{x} . ")");
+    spi_commit();
+}
+$$;
+
+SELECT * FROM test1;
+
+
+-- FIXME
+-- rollback inside cursor loop
+TRUNCATE test1;
+
+DO LANGUAGE plperl $$
+my $sth = spi_query("SELECT * FROM test2 ORDER BY x");
+my $row;
+while (defined($row = spi_fetchrow($sth))) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES (" . $row->{x} . ")");
+    spi_rollback();
+}
+$$;
+
+SELECT * FROM test1;
+
+
+DROP TABLE test1;
+DROP TABLE test2;
diff --git a/src/pl/plpgsql/src/Makefile b/src/pl/plpgsql/src/Makefile
index 76ac247e57..6d8df9a4a0 100644
--- a/src/pl/plpgsql/src/Makefile
+++ b/src/pl/plpgsql/src/Makefile
@@ -26,7 +26,7 @@ DATA = plpgsql.control plpgsql--1.0.sql plpgsql--unpackaged--1.0.sql
 
 REGRESS_OPTS = --dbname=$(PL_TESTDB)
 
-REGRESS = plpgsql_call
+REGRESS = plpgsql_call plpgsql_transaction
 
 all: all-lib
 
diff --git a/src/pl/plpgsql/src/expected/plpgsql_transaction.out b/src/pl/plpgsql/src/expected/plpgsql_transaction.out
new file mode 100644
index 0000000000..8ec22c646c
--- /dev/null
+++ b/src/pl/plpgsql/src/expected/plpgsql_transaction.out
@@ -0,0 +1,241 @@
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+DO
+LANGUAGE plpgsql
+$$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+-- transaction commands not allowed when called in transaction block
+START TRANSACTION;
+CALL transaction_test1();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function transaction_test1() line 6 at COMMIT
+COMMIT;
+START TRANSACTION;
+DO LANGUAGE plpgsql $$ BEGIN COMMIT; END $$;
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function inline_code_block line 1 at COMMIT
+COMMIT;
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+    RETURN 1;
+END
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function transaction_test2() line 6 at COMMIT
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    CALL transaction_test1();
+    RETURN 1;
+END;
+$$;
+SELECT transaction_test3();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function transaction_test1() line 6 at COMMIT
+SQL statement "CALL transaction_test1()"
+PL/pgSQL function transaction_test3() line 3 at SQL statement
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    EXECUTE 'DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$';
+    RETURN 1;
+END;
+$$;
+SELECT transaction_test4();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function inline_code_block line 1 at COMMIT
+SQL statement "DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$"
+PL/pgSQL function transaction_test4() line 3 at EXECUTE
+-- proconfig settings currently disallow transaction statements
+CREATE PROCEDURE transaction_test5()
+LANGUAGE plpgsql
+SET work_mem = 555
+AS $$
+BEGIN
+    COMMIT;
+END;
+$$;
+CALL transaction_test5();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function transaction_test5() line 3 at COMMIT
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+TRUNCATE test1;
+DO LANGUAGE plpgsql $$
+DECLARE
+    r RECORD;
+BEGIN
+    FOR r IN SELECT * FROM test2 ORDER BY x LOOP
+        INSERT INTO test1 (a) VALUES (r.x);
+        COMMIT;
+    END LOOP;
+END;
+$$;
+ERROR:  committing inside a cursor loop is not supported
+CONTEXT:  PL/pgSQL function inline_code_block line 7 at COMMIT
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- rollback inside cursor loop
+TRUNCATE test1;
+DO LANGUAGE plpgsql $$
+DECLARE
+    r RECORD;
+BEGIN
+    FOR r IN SELECT * FROM test2 ORDER BY x LOOP
+        INSERT INTO test1 (a) VALUES (r.x);
+        ROLLBACK;
+    END LOOP;
+END;
+$$;
+ERROR:  cannot abort transaction inside a cursor loop
+CONTEXT:  PL/pgSQL function inline_code_block line 7 at ROLLBACK
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- commit inside block with exception handler
+TRUNCATE test1;
+DO LANGUAGE plpgsql $$
+BEGIN
+    BEGIN
+        INSERT INTO test1 (a) VALUES (1);
+        COMMIT;
+        INSERT INTO test1 (a) VALUES (1/0);
+        COMMIT;
+    EXCEPTION
+        WHEN division_by_zero THEN
+            RAISE NOTICE 'caught division_by_zero';
+    END;
+END;
+$$;
+ERROR:  cannot commit while a subtransaction is active
+CONTEXT:  PL/pgSQL function inline_code_block line 5 at COMMIT
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- rollback inside block with exception handler
+TRUNCATE test1;
+DO LANGUAGE plpgsql $$
+BEGIN
+    BEGIN
+        INSERT INTO test1 (a) VALUES (1);
+        ROLLBACK;
+        INSERT INTO test1 (a) VALUES (1/0);
+        ROLLBACK;
+    EXCEPTION
+        WHEN division_by_zero THEN
+            RAISE NOTICE 'caught division_by_zero';
+    END;
+END;
+$$;
+ERROR:  cannot roll back while a subtransaction is active
+CONTEXT:  PL/pgSQL function inline_code_block line 5 at ROLLBACK
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- COMMIT failures
+DO LANGUAGE plpgsql $$
+BEGIN
+    CREATE TABLE test3 (y int UNIQUE DEFERRABLE INITIALLY DEFERRED);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (1);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (1);
+    INSERT INTO test3 (y) VALUES (2);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (3);  -- won't get here
+END;
+$$;
+ERROR:  duplicate key value violates unique constraint "test3_y_key"
+DETAIL:  Key (y)=(1) already exists.
+CONTEXT:  PL/pgSQL function inline_code_block line 9 at COMMIT
+SELECT * FROM test3;
+ y 
+---
+ 1
+(1 row)
+
+DROP TABLE test1;
+DROP TABLE test2;
+DROP TABLE test3;
diff --git a/src/pl/plpgsql/src/pl_exec.c b/src/pl/plpgsql/src/pl_exec.c
index fa4d573e50..af615deb7e 100644
--- a/src/pl/plpgsql/src/pl_exec.c
+++ b/src/pl/plpgsql/src/pl_exec.c
@@ -215,6 +215,10 @@ static int exec_stmt_dynexecute(PLpgSQL_execstate *estate,
 					 PLpgSQL_stmt_dynexecute *stmt);
 static int exec_stmt_dynfors(PLpgSQL_execstate *estate,
 				  PLpgSQL_stmt_dynfors *stmt);
+static int exec_stmt_commit(PLpgSQL_execstate *estate,
+				PLpgSQL_stmt_commit *stmt);
+static int exec_stmt_rollback(PLpgSQL_execstate *estate,
+				PLpgSQL_stmt_rollback *stmt);
 
 static void plpgsql_estate_setup(PLpgSQL_execstate *estate,
 					 PLpgSQL_function *func,
@@ -1650,6 +1654,14 @@ exec_stmt(PLpgSQL_execstate *estate, PLpgSQL_stmt *stmt)
 			rc = exec_stmt_close(estate, (PLpgSQL_stmt_close *) stmt);
 			break;
 
+		case PLPGSQL_STMT_COMMIT:
+			rc = exec_stmt_commit(estate, (PLpgSQL_stmt_commit *) stmt);
+			break;
+
+		case PLPGSQL_STMT_ROLLBACK:
+			rc = exec_stmt_rollback(estate, (PLpgSQL_stmt_rollback *) stmt);
+			break;
+
 		default:
 			estate->err_stmt = save_estmt;
 			elog(ERROR, "unrecognized cmdtype: %d", stmt->cmd_type);
@@ -4332,6 +4344,57 @@ exec_stmt_close(PLpgSQL_execstate *estate, PLpgSQL_stmt_close *stmt)
 	return PLPGSQL_RC_OK;
 }
 
+/*
+ * exec_stmt_commit
+ *
+ * Commit the transaction.
+ */
+static int
+exec_stmt_commit(PLpgSQL_execstate *estate, PLpgSQL_stmt_commit *stmt)
+{
+	/*
+	 * XXX This could be implemented by converting the pinned portals to
+	 * holdable ones and organizing the cleanup separately.
+	 */
+	if (ThereArePinnedPortals())
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("committing inside a cursor loop is not supported")));
+
+	SPI_commit();
+	SPI_start_transaction();
+
+	estate->simple_eval_estate = NULL;
+	plpgsql_create_econtext(estate);
+
+	return PLPGSQL_RC_OK;
+}
+
+/*
+ * exec_stmt_rollback
+ *
+ * Abort the transaction.
+ */
+static int
+exec_stmt_rollback(PLpgSQL_execstate *estate, PLpgSQL_stmt_rollback *stmt)
+{
+	/*
+	 * Unlike the COMMIT case above, this might not make sense at all,
+	 * especially if the query driving the cursor loop has side effects.
+	 */
+	if (ThereArePinnedPortals())
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("cannot abort transaction inside a cursor loop")));
+
+	SPI_rollback();
+	SPI_start_transaction();
+
+	estate->simple_eval_estate = NULL;
+	plpgsql_create_econtext(estate);
+
+	return PLPGSQL_RC_OK;
+}
 
 /* ----------
  * exec_assign_expr			Put an expression's result into a variable.
@@ -6830,8 +6893,7 @@ plpgsql_xact_cb(XactEvent event, void *arg)
 	 */
 	if (event == XACT_EVENT_COMMIT || event == XACT_EVENT_PREPARE)
 	{
-		/* Shouldn't be any econtext stack entries left at commit */
-		Assert(simple_econtext_stack == NULL);
+		simple_econtext_stack = NULL;
 
 		if (shared_simple_eval_estate)
 			FreeExecutorState(shared_simple_eval_estate);
diff --git a/src/pl/plpgsql/src/pl_funcs.c b/src/pl/plpgsql/src/pl_funcs.c
index be779b6fc4..c8667b054a 100644
--- a/src/pl/plpgsql/src/pl_funcs.c
+++ b/src/pl/plpgsql/src/pl_funcs.c
@@ -284,6 +284,10 @@ plpgsql_stmt_typename(PLpgSQL_stmt *stmt)
 			return "CLOSE";
 		case PLPGSQL_STMT_PERFORM:
 			return "PERFORM";
+		case PLPGSQL_STMT_COMMIT:
+			return "COMMIT";
+		case PLPGSQL_STMT_ROLLBACK:
+			return "ROLLBACK";
 	}
 
 	return "unknown";
@@ -363,6 +367,8 @@ static void free_open(PLpgSQL_stmt_open *stmt);
 static void free_fetch(PLpgSQL_stmt_fetch *stmt);
 static void free_close(PLpgSQL_stmt_close *stmt);
 static void free_perform(PLpgSQL_stmt_perform *stmt);
+static void free_commit(PLpgSQL_stmt_commit *stmt);
+static void free_rollback(PLpgSQL_stmt_rollback *stmt);
 static void free_expr(PLpgSQL_expr *expr);
 
 
@@ -443,6 +449,12 @@ free_stmt(PLpgSQL_stmt *stmt)
 		case PLPGSQL_STMT_PERFORM:
 			free_perform((PLpgSQL_stmt_perform *) stmt);
 			break;
+		case PLPGSQL_STMT_COMMIT:
+			free_commit((PLpgSQL_stmt_commit *) stmt);
+			break;
+		case PLPGSQL_STMT_ROLLBACK:
+			free_rollback((PLpgSQL_stmt_rollback *) stmt);
+			break;
 		default:
 			elog(ERROR, "unrecognized cmd_type: %d", stmt->cmd_type);
 			break;
@@ -590,6 +602,16 @@ free_perform(PLpgSQL_stmt_perform *stmt)
 	free_expr(stmt->expr);
 }
 
+static void
+free_commit(PLpgSQL_stmt_commit *stmt)
+{
+}
+
+static void
+free_rollback(PLpgSQL_stmt_rollback *stmt)
+{
+}
+
 static void
 free_exit(PLpgSQL_stmt_exit *stmt)
 {
@@ -777,6 +799,8 @@ static void dump_fetch(PLpgSQL_stmt_fetch *stmt);
 static void dump_cursor_direction(PLpgSQL_stmt_fetch *stmt);
 static void dump_close(PLpgSQL_stmt_close *stmt);
 static void dump_perform(PLpgSQL_stmt_perform *stmt);
+static void dump_commit(PLpgSQL_stmt_commit *stmt);
+static void dump_rollback(PLpgSQL_stmt_rollback *stmt);
 static void dump_expr(PLpgSQL_expr *expr);
 
 
@@ -867,6 +891,12 @@ dump_stmt(PLpgSQL_stmt *stmt)
 		case PLPGSQL_STMT_PERFORM:
 			dump_perform((PLpgSQL_stmt_perform *) stmt);
 			break;
+		case PLPGSQL_STMT_COMMIT:
+			dump_commit((PLpgSQL_stmt_commit *) stmt);
+			break;
+		case PLPGSQL_STMT_ROLLBACK:
+			dump_rollback((PLpgSQL_stmt_rollback *) stmt);
+			break;
 		default:
 			elog(ERROR, "unrecognized cmd_type: %d", stmt->cmd_type);
 			break;
@@ -1239,6 +1269,20 @@ dump_perform(PLpgSQL_stmt_perform *stmt)
 	printf("\n");
 }
 
+static void
+dump_commit(PLpgSQL_stmt_commit *stmt)
+{
+	dump_ind();
+	printf("COMMIT\n");
+}
+
+static void
+dump_rollback(PLpgSQL_stmt_rollback *stmt)
+{
+	dump_ind();
+	printf("ROLLBACK\n");
+}
+
 static void
 dump_exit(PLpgSQL_stmt_exit *stmt)
 {
diff --git a/src/pl/plpgsql/src/pl_gram.y b/src/pl/plpgsql/src/pl_gram.y
index e802440b45..7589e2df0f 100644
--- a/src/pl/plpgsql/src/pl_gram.y
+++ b/src/pl/plpgsql/src/pl_gram.y
@@ -198,6 +198,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %type <stmt>	stmt_return stmt_raise stmt_assert stmt_execsql
 %type <stmt>	stmt_dynexecute stmt_for stmt_perform stmt_getdiag
 %type <stmt>	stmt_open stmt_fetch stmt_move stmt_close stmt_null
+%type <stmt>	stmt_commit stmt_rollback
 %type <stmt>	stmt_case stmt_foreach_a
 
 %type <list>	proc_exceptions
@@ -260,6 +261,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %token <keyword>	K_COLLATE
 %token <keyword>	K_COLUMN
 %token <keyword>	K_COLUMN_NAME
+%token <keyword>	K_COMMIT
 %token <keyword>	K_CONSTANT
 %token <keyword>	K_CONSTRAINT
 %token <keyword>	K_CONSTRAINT_NAME
@@ -325,6 +327,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %token <keyword>	K_RETURN
 %token <keyword>	K_RETURNED_SQLSTATE
 %token <keyword>	K_REVERSE
+%token <keyword>	K_ROLLBACK
 %token <keyword>	K_ROW_COUNT
 %token <keyword>	K_ROWTYPE
 %token <keyword>	K_SCHEMA
@@ -897,6 +900,10 @@ proc_stmt		: pl_block ';'
 						{ $$ = $1; }
 				| stmt_null
 						{ $$ = $1; }
+				| stmt_commit
+						{ $$ = $1; }
+				| stmt_rollback
+						{ $$ = $1; }
 				;
 
 stmt_perform	: K_PERFORM expr_until_semi
@@ -2151,6 +2158,31 @@ stmt_null		: K_NULL ';'
 					}
 				;
 
+stmt_commit		: K_COMMIT ';'
+					{
+						PLpgSQL_stmt_commit *new;
+
+						new = palloc(sizeof(PLpgSQL_stmt_commit));
+						new->cmd_type = PLPGSQL_STMT_COMMIT;
+						new->lineno = plpgsql_location_to_lineno(@1);
+
+						$$ = (PLpgSQL_stmt *)new;
+					}
+				;
+
+stmt_rollback	: K_ROLLBACK ';'
+					{
+						PLpgSQL_stmt_rollback *new;
+
+						new = palloc(sizeof(PLpgSQL_stmt_rollback));
+						new->cmd_type = PLPGSQL_STMT_ROLLBACK;
+						new->lineno = plpgsql_location_to_lineno(@1);
+
+						$$ = (PLpgSQL_stmt *)new;
+					}
+				;
+
+
 cursor_variable	: T_DATUM
 					{
 						/*
@@ -2387,6 +2419,7 @@ unreserved_keyword	:
 				| K_COLLATE
 				| K_COLUMN
 				| K_COLUMN_NAME
+				| K_COMMIT
 				| K_CONSTANT
 				| K_CONSTRAINT
 				| K_CONSTRAINT_NAME
@@ -2438,6 +2471,7 @@ unreserved_keyword	:
 				| K_RETURN
 				| K_RETURNED_SQLSTATE
 				| K_REVERSE
+				| K_ROLLBACK
 				| K_ROW_COUNT
 				| K_ROWTYPE
 				| K_SCHEMA
diff --git a/src/pl/plpgsql/src/pl_handler.c b/src/pl/plpgsql/src/pl_handler.c
index 1ebb7a7b5e..2b0568a2f4 100644
--- a/src/pl/plpgsql/src/pl_handler.c
+++ b/src/pl/plpgsql/src/pl_handler.c
@@ -219,15 +219,20 @@ PG_FUNCTION_INFO_V1(plpgsql_call_handler);
 Datum
 plpgsql_call_handler(PG_FUNCTION_ARGS)
 {
+	bool		nonatomic;
 	PLpgSQL_function *func;
 	PLpgSQL_execstate *save_cur_estate;
 	Datum		retval;
 	int			rc;
 
+	nonatomic = fcinfo->context &&
+		IsA(fcinfo->context, CallContext) &&
+		!castNode(CallContext, fcinfo->context)->atomic;
+
 	/*
 	 * Connect to SPI manager
 	 */
-	if ((rc = SPI_connect()) != SPI_OK_CONNECT)
+	if ((rc = SPI_connect_ext(nonatomic ? SPI_OPT_NONATOMIC : 0)) != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed: %s", SPI_result_code_string(rc));
 
 	/* Find or compile the function */
@@ -255,7 +260,9 @@ plpgsql_call_handler(PG_FUNCTION_ARGS)
 			retval = (Datum) 0;
 		}
 		else
+		{
 			retval = plpgsql_exec_function(func, fcinfo, NULL);
+		}
 	}
 	PG_CATCH();
 	{
@@ -301,7 +308,7 @@ plpgsql_inline_handler(PG_FUNCTION_ARGS)
 	/*
 	 * Connect to SPI manager
 	 */
-	if ((rc = SPI_connect()) != SPI_OK_CONNECT)
+	if ((rc = SPI_connect_ext(codeblock->atomic ? 0 : SPI_OPT_NONATOMIC)) != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed: %s", SPI_result_code_string(rc));
 
 	/* Compile the anonymous code block */
diff --git a/src/pl/plpgsql/src/pl_scanner.c b/src/pl/plpgsql/src/pl_scanner.c
index 553be8c93c..a172031db2 100644
--- a/src/pl/plpgsql/src/pl_scanner.c
+++ b/src/pl/plpgsql/src/pl_scanner.c
@@ -106,6 +106,7 @@ static const ScanKeyword unreserved_keywords[] = {
 	PG_KEYWORD("collate", K_COLLATE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("column", K_COLUMN, UNRESERVED_KEYWORD)
 	PG_KEYWORD("column_name", K_COLUMN_NAME, UNRESERVED_KEYWORD)
+	PG_KEYWORD("commit", K_COMMIT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constant", K_CONSTANT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constraint", K_CONSTRAINT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constraint_name", K_CONSTRAINT_NAME, UNRESERVED_KEYWORD)
@@ -158,6 +159,7 @@ static const ScanKeyword unreserved_keywords[] = {
 	PG_KEYWORD("return", K_RETURN, UNRESERVED_KEYWORD)
 	PG_KEYWORD("returned_sqlstate", K_RETURNED_SQLSTATE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("reverse", K_REVERSE, UNRESERVED_KEYWORD)
+	PG_KEYWORD("rollback", K_ROLLBACK, UNRESERVED_KEYWORD)
 	PG_KEYWORD("row_count", K_ROW_COUNT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("rowtype", K_ROWTYPE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("schema", K_SCHEMA, UNRESERVED_KEYWORD)
diff --git a/src/pl/plpgsql/src/plpgsql.h b/src/pl/plpgsql/src/plpgsql.h
index 39bd82acd1..59a5f40dd8 100644
--- a/src/pl/plpgsql/src/plpgsql.h
+++ b/src/pl/plpgsql/src/plpgsql.h
@@ -105,7 +105,9 @@ typedef enum PLpgSQL_stmt_type
 	PLPGSQL_STMT_OPEN,
 	PLPGSQL_STMT_FETCH,
 	PLPGSQL_STMT_CLOSE,
-	PLPGSQL_STMT_PERFORM
+	PLPGSQL_STMT_PERFORM,
+	PLPGSQL_STMT_COMMIT,
+	PLPGSQL_STMT_ROLLBACK
 } PLpgSQL_stmt_type;
 
 /*
@@ -433,6 +435,24 @@ typedef struct PLpgSQL_stmt_perform
 	PLpgSQL_expr *expr;
 } PLpgSQL_stmt_perform;
 
+/*
+ * COMMIT statement
+ */
+typedef struct PLpgSQL_stmt_commit
+{
+	PLpgSQL_stmt_type cmd_type;
+	int			lineno;
+} PLpgSQL_stmt_commit;
+
+/*
+ * ROLLBACK statement
+ */
+typedef struct PLpgSQL_stmt_rollback
+{
+	PLpgSQL_stmt_type cmd_type;
+	int			lineno;
+} PLpgSQL_stmt_rollback;
+
 /*
  * GET DIAGNOSTICS item
  */
diff --git a/src/pl/plpgsql/src/sql/plpgsql_transaction.sql b/src/pl/plpgsql/src/sql/plpgsql_transaction.sql
new file mode 100644
index 0000000000..02ee735079
--- /dev/null
+++ b/src/pl/plpgsql/src/sql/plpgsql_transaction.sql
@@ -0,0 +1,215 @@
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+DO
+LANGUAGE plpgsql
+$$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+SELECT * FROM test1;
+
+
+-- transaction commands not allowed when called in transaction block
+START TRANSACTION;
+CALL transaction_test1();
+COMMIT;
+
+START TRANSACTION;
+DO LANGUAGE plpgsql $$ BEGIN COMMIT; END $$;
+COMMIT;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+    RETURN 1;
+END
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    CALL transaction_test1();
+    RETURN 1;
+END;
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    EXECUTE 'DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$';
+    RETURN 1;
+END;
+$$;
+
+SELECT transaction_test4();
+
+
+-- proconfig settings currently disallow transaction statements
+CREATE PROCEDURE transaction_test5()
+LANGUAGE plpgsql
+SET work_mem = 555
+AS $$
+BEGIN
+    COMMIT;
+END;
+$$;
+
+CALL transaction_test5();
+
+
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+
+TRUNCATE test1;
+
+DO LANGUAGE plpgsql $$
+DECLARE
+    r RECORD;
+BEGIN
+    FOR r IN SELECT * FROM test2 ORDER BY x LOOP
+        INSERT INTO test1 (a) VALUES (r.x);
+        COMMIT;
+    END LOOP;
+END;
+$$;
+
+SELECT * FROM test1;
+
+
+-- rollback inside cursor loop
+TRUNCATE test1;
+
+DO LANGUAGE plpgsql $$
+DECLARE
+    r RECORD;
+BEGIN
+    FOR r IN SELECT * FROM test2 ORDER BY x LOOP
+        INSERT INTO test1 (a) VALUES (r.x);
+        ROLLBACK;
+    END LOOP;
+END;
+$$;
+
+SELECT * FROM test1;
+
+
+-- commit inside block with exception handler
+TRUNCATE test1;
+
+DO LANGUAGE plpgsql $$
+BEGIN
+    BEGIN
+        INSERT INTO test1 (a) VALUES (1);
+        COMMIT;
+        INSERT INTO test1 (a) VALUES (1/0);
+        COMMIT;
+    EXCEPTION
+        WHEN division_by_zero THEN
+            RAISE NOTICE 'caught division_by_zero';
+    END;
+END;
+$$;
+
+SELECT * FROM test1;
+
+
+-- rollback inside block with exception handler
+TRUNCATE test1;
+
+DO LANGUAGE plpgsql $$
+BEGIN
+    BEGIN
+        INSERT INTO test1 (a) VALUES (1);
+        ROLLBACK;
+        INSERT INTO test1 (a) VALUES (1/0);
+        ROLLBACK;
+    EXCEPTION
+        WHEN division_by_zero THEN
+            RAISE NOTICE 'caught division_by_zero';
+    END;
+END;
+$$;
+
+SELECT * FROM test1;
+
+
+-- COMMIT failures
+DO LANGUAGE plpgsql $$
+BEGIN
+    CREATE TABLE test3 (y int UNIQUE DEFERRABLE INITIALLY DEFERRED);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (1);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (1);
+    INSERT INTO test3 (y) VALUES (2);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (3);  -- won't get here
+END;
+$$;
+
+SELECT * FROM test3;
+
+
+DROP TABLE test1;
+DROP TABLE test2;
+DROP TABLE test3;
diff --git a/src/pl/plpython/Makefile b/src/pl/plpython/Makefile
index cc91afebde..d09910835d 100644
--- a/src/pl/plpython/Makefile
+++ b/src/pl/plpython/Makefile
@@ -90,6 +90,7 @@ REGRESS = \
 	plpython_quote \
 	plpython_composite \
 	plpython_subtransaction \
+	plpython_transaction \
 	plpython_drop
 
 REGRESS_PLPYTHON3_MANGLE := $(REGRESS)
diff --git a/src/pl/plpython/expected/plpython_test.out b/src/pl/plpython/expected/plpython_test.out
index 847e4cc412..39b994f446 100644
--- a/src/pl/plpython/expected/plpython_test.out
+++ b/src/pl/plpython/expected/plpython_test.out
@@ -48,6 +48,7 @@ select module_contents();
  Error
  Fatal
  SPIError
+ commit
  cursor
  debug
  error
@@ -60,10 +61,11 @@ select module_contents();
  quote_ident
  quote_literal
  quote_nullable
+ rollback
  spiexceptions
  subtransaction
  warning
-(18 rows)
+(20 rows)
 
 CREATE FUNCTION elog_test_basic() RETURNS void
 AS $$
diff --git a/src/pl/plpython/expected/plpython_transaction.out b/src/pl/plpython/expected/plpython_transaction.out
new file mode 100644
index 0000000000..a94e136715
--- /dev/null
+++ b/src/pl/plpython/expected/plpython_transaction.out
@@ -0,0 +1,144 @@
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+DO
+LANGUAGE plpythonu
+$$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+return 1
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/Python function "transaction_test2"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("CALL transaction_test1()")
+return 1
+$$;
+SELECT transaction_test3();
+ERROR:  spiexceptions.InvalidTransactionTermination: invalid transaction termination
+CONTEXT:  Traceback (most recent call last):
+  PL/Python function "transaction_test3", line 2, in <module>
+    plpy.execute("CALL transaction_test1()")
+PL/Python function "transaction_test3"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$")
+return 1
+$$;
+SELECT transaction_test4();
+ERROR:  spiexceptions.InvalidTransactionTermination: invalid transaction termination
+CONTEXT:  Traceback (most recent call last):
+  PL/Python function "transaction_test4", line 2, in <module>
+    plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$")
+PL/Python function "transaction_test4"
+-- commit inside subtransaction (prohibited)
+DO LANGUAGE plpythonu $$
+with plpy.subtransaction():
+    plpy.commit()
+$$;
+WARNING:  forcibly aborting a subtransaction that has not been exited
+ERROR:  cannot commit while a subtransaction is active
+CONTEXT:  PL/Python anonymous code block
+-- FIXME
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+TRUNCATE test1;
+DO LANGUAGE plpythonu $$
+for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%s)" % row['x'])
+    plpy.commit()
+$$;
+ERROR:  ValueError: iterating a cursor in an aborted subtransaction
+CONTEXT:  Traceback (most recent call last):
+  PL/Python anonymous code block, line 2, in <module>
+    for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
+PL/Python anonymous code block
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+(1 row)
+
+-- FIXME
+-- rollback inside cursor loop
+TRUNCATE test1;
+DO LANGUAGE plpythonu $$
+for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%s)" % row['x'])
+    plpy.rollback()
+$$;
+ERROR:  ValueError: iterating a cursor in an aborted subtransaction
+CONTEXT:  Traceback (most recent call last):
+  PL/Python anonymous code block, line 2, in <module>
+    for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
+PL/Python anonymous code block
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+DROP TABLE test1;
+DROP TABLE test2;
diff --git a/src/pl/plpython/plpy_main.c b/src/pl/plpython/plpy_main.c
index 695de30583..527ba67fe1 100644
--- a/src/pl/plpython/plpy_main.c
+++ b/src/pl/plpython/plpy_main.c
@@ -219,14 +219,19 @@ plpython2_validator(PG_FUNCTION_ARGS)
 Datum
 plpython_call_handler(PG_FUNCTION_ARGS)
 {
+	bool		nonatomic;
 	Datum		retval;
 	PLyExecutionContext *exec_ctx;
 	ErrorContextCallback plerrcontext;
 
 	PLy_initialize();
 
+	nonatomic = fcinfo->context &&
+		IsA(fcinfo->context, CallContext) &&
+		!castNode(CallContext, fcinfo->context)->atomic;
+
 	/* Note: SPI_finish() happens in plpy_exec.c, which is dubious design */
-	if (SPI_connect() != SPI_OK_CONNECT)
+	if (SPI_connect_ext(nonatomic ? SPI_OPT_NONATOMIC : 0) != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed");
 
 	/*
@@ -303,7 +308,7 @@ plpython_inline_handler(PG_FUNCTION_ARGS)
 	PLy_initialize();
 
 	/* Note: SPI_finish() happens in plpy_exec.c, which is dubious design */
-	if (SPI_connect() != SPI_OK_CONNECT)
+	if (SPI_connect_ext(codeblock->atomic ? 0 : SPI_OPT_NONATOMIC) != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed");
 
 	MemSet(&fake_fcinfo, 0, sizeof(fake_fcinfo));
@@ -435,7 +440,7 @@ PLy_push_execution_context(void)
 	PLyExecutionContext *context;
 
 	context = (PLyExecutionContext *)
-		MemoryContextAlloc(TopTransactionContext, sizeof(PLyExecutionContext));
+		MemoryContextAlloc(PortalContext, sizeof(PLyExecutionContext));
 	context->curr_proc = NULL;
 	context->scratch_ctx = NULL;
 	context->next = PLy_execution_contexts;
diff --git a/src/pl/plpython/plpy_plpymodule.c b/src/pl/plpython/plpy_plpymodule.c
index 23f99e20ca..3d8983b3b3 100644
--- a/src/pl/plpython/plpy_plpymodule.c
+++ b/src/pl/plpython/plpy_plpymodule.c
@@ -6,8 +6,10 @@
 
 #include "postgres.h"
 
+#include "access/xact.h"
 #include "mb/pg_wchar.h"
 #include "utils/builtins.h"
+#include "utils/snapmgr.h"
 
 #include "plpython.h"
 
@@ -15,6 +17,7 @@
 
 #include "plpy_cursorobject.h"
 #include "plpy_elog.h"
+#include "plpy_main.h"
 #include "plpy_planobject.h"
 #include "plpy_resultobject.h"
 #include "plpy_spi.h"
@@ -41,6 +44,8 @@ static PyObject *PLy_fatal(PyObject *self, PyObject *args, PyObject *kw);
 static PyObject *PLy_quote_literal(PyObject *self, PyObject *args);
 static PyObject *PLy_quote_nullable(PyObject *self, PyObject *args);
 static PyObject *PLy_quote_ident(PyObject *self, PyObject *args);
+static PyObject *PLy_commit(PyObject *self, PyObject *args);
+static PyObject *PLy_rollback(PyObject *self, PyObject *args);
 
 
 /* A list of all known exceptions, generated from backend/utils/errcodes.txt */
@@ -95,6 +100,12 @@ static PyMethodDef PLy_methods[] = {
 	 */
 	{"cursor", PLy_cursor, METH_VARARGS, NULL},
 
+	/*
+	 * transaction control
+	 */
+	{"commit", PLy_commit, METH_NOARGS, NULL},
+	{"rollback", PLy_rollback, METH_NOARGS, NULL},
+
 	{NULL, NULL, 0, NULL}
 };
 
@@ -577,3 +588,31 @@ PLy_output(volatile int level, PyObject *self, PyObject *args, PyObject *kw)
 	 */
 	Py_RETURN_NONE;
 }
+
+static PyObject *
+PLy_commit(PyObject *self, PyObject *args)
+{
+	PLyExecutionContext *exec_ctx = PLy_current_execution_context();
+
+	SPI_commit();
+	SPI_start_transaction();
+
+	/* was cleared at transaction end, reset pointer */
+	exec_ctx->scratch_ctx = NULL;
+
+	Py_RETURN_NONE;
+}
+
+static PyObject *
+PLy_rollback(PyObject *self, PyObject *args)
+{
+	PLyExecutionContext *exec_ctx = PLy_current_execution_context();
+
+	SPI_rollback();
+	SPI_start_transaction();
+
+	/* was cleared at transaction end, reset pointer */
+	exec_ctx->scratch_ctx = NULL;
+
+	Py_RETURN_NONE;
+}
diff --git a/src/pl/plpython/sql/plpython_transaction.sql b/src/pl/plpython/sql/plpython_transaction.sql
new file mode 100644
index 0000000000..0cf74fed54
--- /dev/null
+++ b/src/pl/plpython/sql/plpython_transaction.sql
@@ -0,0 +1,117 @@
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+DO
+LANGUAGE plpythonu
+$$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+return 1
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("CALL transaction_test1()")
+return 1
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$")
+return 1
+$$;
+
+SELECT transaction_test4();
+
+
+-- commit inside subtransaction (prohibited)
+DO LANGUAGE plpythonu $$
+with plpy.subtransaction():
+    plpy.commit()
+$$;
+
+
+-- FIXME
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+
+TRUNCATE test1;
+
+DO LANGUAGE plpythonu $$
+for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%s)" % row['x'])
+    plpy.commit()
+$$;
+
+SELECT * FROM test1;
+
+
+-- FIXME
+-- rollback inside cursor loop
+TRUNCATE test1;
+
+DO LANGUAGE plpythonu $$
+for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%s)" % row['x'])
+    plpy.rollback()
+$$;
+
+SELECT * FROM test1;
+
+
+DROP TABLE test1;
+DROP TABLE test2;
diff --git a/src/pl/tcl/Makefile b/src/pl/tcl/Makefile
index 6a92a9b6aa..ef61ee596e 100644
--- a/src/pl/tcl/Makefile
+++ b/src/pl/tcl/Makefile
@@ -28,7 +28,7 @@ DATA = pltcl.control pltcl--1.0.sql pltcl--unpackaged--1.0.sql \
        pltclu.control pltclu--1.0.sql pltclu--unpackaged--1.0.sql
 
 REGRESS_OPTS = --dbname=$(PL_TESTDB) --load-extension=pltcl
-REGRESS = pltcl_setup pltcl_queries pltcl_call pltcl_start_proc pltcl_subxact pltcl_unicode
+REGRESS = pltcl_setup pltcl_queries pltcl_call pltcl_start_proc pltcl_subxact pltcl_unicode pltcl_transaction
 
 # Tcl on win32 ships with import libraries only for Microsoft Visual C++,
 # which are not compatible with mingw gcc. Therefore we need to build a
diff --git a/src/pl/tcl/expected/pltcl_transaction.out b/src/pl/tcl/expected/pltcl_transaction.out
new file mode 100644
index 0000000000..007204b99a
--- /dev/null
+++ b/src/pl/tcl/expected/pltcl_transaction.out
@@ -0,0 +1,100 @@
+-- suppress CONTEXT so that function OIDs aren't in output
+\set VERBOSITY terse
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+return 1
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE pltcl
+AS $$
+spi_exec "CALL transaction_test1()"
+return 1
+$$;
+SELECT transaction_test3();
+ERROR:  invalid transaction termination
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+TRUNCATE test1;
+CREATE PROCEDURE transaction_test4a()
+LANGUAGE pltcl
+AS $$
+spi_exec -array row "SELECT * FROM test2 ORDER BY x" {
+    spi_exec "INSERT INTO test1 (a) VALUES ($row(x))"
+    commit
+}
+$$;
+CALL transaction_test4a();
+ERROR:  cannot commit while a subtransaction is active
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- rollback inside cursor loop
+TRUNCATE test1;
+CREATE PROCEDURE transaction_test4b()
+LANGUAGE pltcl
+AS $$
+spi_exec -array row "SELECT * FROM test2 ORDER BY x" {
+    spi_exec "INSERT INTO test1 (a) VALUES ($row(x))"
+    rollback
+}
+$$;
+CALL transaction_test4b();
+ERROR:  cannot roll back while a subtransaction is active
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+DROP TABLE test1;
+DROP TABLE test2;
diff --git a/src/pl/tcl/pltcl.c b/src/pl/tcl/pltcl.c
index 8069784151..770b7da462 100644
--- a/src/pl/tcl/pltcl.c
+++ b/src/pl/tcl/pltcl.c
@@ -312,6 +312,10 @@ static int pltcl_SPI_lastoid(ClientData cdata, Tcl_Interp *interp,
 				  int objc, Tcl_Obj *const objv[]);
 static int pltcl_subtransaction(ClientData cdata, Tcl_Interp *interp,
 					 int objc, Tcl_Obj *const objv[]);
+static int pltcl_commit(ClientData cdata, Tcl_Interp *interp,
+					 int objc, Tcl_Obj *const objv[]);
+static int pltcl_rollback(ClientData cdata, Tcl_Interp *interp,
+					 int objc, Tcl_Obj *const objv[]);
 
 static void pltcl_subtrans_begin(MemoryContext oldcontext,
 					 ResourceOwner oldowner);
@@ -524,6 +528,10 @@ pltcl_init_interp(pltcl_interp_desc *interp_desc, Oid prolang, bool pltrusted)
 						 pltcl_SPI_lastoid, NULL, NULL);
 	Tcl_CreateObjCommand(interp, "subtransaction",
 						 pltcl_subtransaction, NULL, NULL);
+	Tcl_CreateObjCommand(interp, "commit",
+						 pltcl_commit, NULL, NULL);
+	Tcl_CreateObjCommand(interp, "rollback",
+						 pltcl_rollback, NULL, NULL);
 
 	/************************************************************
 	 * Call the appropriate start_proc, if there is one.
@@ -797,6 +805,7 @@ static Datum
 pltcl_func_handler(PG_FUNCTION_ARGS, pltcl_call_state *call_state,
 				   bool pltrusted)
 {
+	bool		nonatomic;
 	pltcl_proc_desc *prodesc;
 	Tcl_Interp *volatile interp;
 	Tcl_Obj    *tcl_cmd;
@@ -804,8 +813,12 @@ pltcl_func_handler(PG_FUNCTION_ARGS, pltcl_call_state *call_state,
 	int			tcl_rc;
 	Datum		retval;
 
+	nonatomic = fcinfo->context &&
+		IsA(fcinfo->context, CallContext) &&
+		!castNode(CallContext, fcinfo->context)->atomic;
+
 	/* Connect to SPI manager */
-	if (SPI_connect() != SPI_OK_CONNECT)
+	if (SPI_connect_ext(nonatomic ? SPI_OPT_NONATOMIC : 0) != SPI_OK_CONNECT)
 		elog(ERROR, "could not connect to SPI manager");
 
 	/* Find or compile the function */
@@ -2936,6 +2949,38 @@ pltcl_subtransaction(ClientData cdata, Tcl_Interp *interp,
 }
 
 
+/**********************************************************************
+ * pltcl_commit()
+ *
+ * Commit the transaction and start a new one.
+ **********************************************************************/
+static int
+pltcl_commit(ClientData cdata, Tcl_Interp *interp,
+			 int objc, Tcl_Obj *const objv[])
+{
+	SPI_commit();
+	SPI_start_transaction();
+
+	return TCL_OK;
+}
+
+
+/**********************************************************************
+ * pltcl_rollback()
+ *
+ * Abort the transaction and start a new one.
+ **********************************************************************/
+static int
+pltcl_rollback(ClientData cdata, Tcl_Interp *interp,
+			   int objc, Tcl_Obj *const objv[])
+{
+	SPI_rollback();
+	SPI_start_transaction();
+
+	return TCL_OK;
+}
+
+
 /**********************************************************************
  * pltcl_set_tuple_values() - Set variables for all attributes
  *				  of a given tuple
diff --git a/src/pl/tcl/sql/pltcl_transaction.sql b/src/pl/tcl/sql/pltcl_transaction.sql
new file mode 100644
index 0000000000..c752faf665
--- /dev/null
+++ b/src/pl/tcl/sql/pltcl_transaction.sql
@@ -0,0 +1,98 @@
+-- suppress CONTEXT so that function OIDs aren't in output
+\set VERBOSITY terse
+
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+return 1
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE pltcl
+AS $$
+spi_exec "CALL transaction_test1()"
+return 1
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+
+TRUNCATE test1;
+
+CREATE PROCEDURE transaction_test4a()
+LANGUAGE pltcl
+AS $$
+spi_exec -array row "SELECT * FROM test2 ORDER BY x" {
+    spi_exec "INSERT INTO test1 (a) VALUES ($row(x))"
+    commit
+}
+$$;
+
+CALL transaction_test4a();
+
+SELECT * FROM test1;
+
+
+-- rollback inside cursor loop
+TRUNCATE test1;
+
+CREATE PROCEDURE transaction_test4b()
+LANGUAGE pltcl
+AS $$
+spi_exec -array row "SELECT * FROM test2 ORDER BY x" {
+    spi_exec "INSERT INTO test1 (a) VALUES ($row(x))"
+    rollback
+}
+$$;
+
+CALL transaction_test4b();
+
+SELECT * FROM test1;
+
+
+DROP TABLE test1;
+DROP TABLE test2;

base-commit: 8526bcb2df76d5171b4f4d6dc7a97560a73a5eff
-- 
2.15.1

#35Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: Peter Eisentraut (#34)
1 attachment(s)
Re: [HACKERS] Transaction control in procedures

A merge conflict has arisen, so for simplicity, here is an updated patch.

On 12/20/17 10:08, Peter Eisentraut wrote:

Updated patch attached.

I have addressed the most recent review comments I believe.

The question about what happens to cursor loops in PL/Perl and PL/Python
would be addressed by the separate thread "portal pinning". The test
cases in this patch are currently marked by FIXMEs.

I have changed the SPI API a bit. I got rid of SPI_set_nonatomic() and
instead introduced SPI_connect_ext() that you can pass flags to. The
advantage of that is that in the normal case we can continue to use the
existing memory contexts, so nothing changes for existing uses, which
seems desirable. (This also appears to address some sporadic test
failures in PL/Perl.)

I have also cleaned up the changes in portalmem.c further, so the
changes are now even smaller.

The commit message in this patch contains more details about some of
these changes.

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

Attachments:

v6-0001-Transaction-control-in-PL-procedures.patchtext/plain; charset=UTF-8; name=v6-0001-Transaction-control-in-PL-procedures.patch; x-mac-creator=0; x-mac-type=0Download
From 86db8254bcd93585f1036b755a54ae1608ed092f Mon Sep 17 00:00:00 2001
From: Peter Eisentraut <peter_e@gmx.net>
Date: Fri, 5 Jan 2018 16:27:53 -0500
Subject: [PATCH v6] Transaction control in PL procedures

In each of the supplied procedural languages (PL/pgSQL, PL/Perl,
PL/Python, PL/Tcl), add language-specific commit and rollback
functions/commands to control transactions in procedures in that
language.  Add similar underlying functions to SPI.  Some additional
cleanup so that transaction commit or abort doesn't blow away data
structures still used by the procedure call.  Add execution context
tracking to CALL and DO statements so that transaction control commands
can only be issued in top-level procedure and block calls, not function
calls or other procedure or block calls.

- SPI

Add a new function SPI_connect_ext() that is like SPI_connect() but
allows passing option flags.  The only option flag right now is
SPI_OPT_NONATOMIC.  A nonatomic SPI connection can execute transaction
control commands, otherwise it's not allowed.  This is meant to be
passed down from CALL and DO statements which themselves know in which
context they are called.  A nonatomic SPI connection uses different
memory management.  A normal SPI connection allocates its memory in
TopTransactionContext.  For nonatomic connections we use PortalContext
instead.  As the comment in SPI_connect_ext() (previously SPI_connect())
indicates, one could potentially use PortalContext in all cases, but it
seems safest to leave the existing uses alone, because this stuff is
complicated enough already.

SPI also gets new functions SPI_start_transaction(), SPI_commit(), and
SPI_rollback(), which can be used by PLs to implement their transaction
control logic.

- portalmem.c

Some adjustments were made in the code that cleans up portals at
transaction abort.  The portal code could already handle a command
*committing* a transaction and continuing (e.g., VACUUM), but it was not
quite prepared for a command *aborting* a transaction and continuing.

In AtAbort_Portals(), remove the code that marks an active portal as
failed.  As the comment there already predicted, this doesn't work if
the running command wants to keep running after transaction abort.  And
it's actually not necessary, because pquery.c is careful to run all
portal code in a PG_TRY block and explicitly runs MarkPortalFailed() if
there is an exception.  So the code in AtAbort_Portals() is never used
anyway.

In AtAbort_Portals() and AtCleanup_Portals(), we need to be careful not
to clean up active portals too much.  This mirrors similar code in
PreCommit_Portals().

- PL/Perl

Gets new functions spi_commit() and spi_rollback()

- PL/pgSQL

Gets new commands COMMIT and ROLLBACK.

Update the PL/SQL porting example in the documentation to reflect that
transactions are now possible in procedures.

- PL/Python

Gets new functions plpy.commit and plpy.rollback.

- PL/Tcl

Gets new commands commit and rollback.
---
 doc/src/sgml/plperl.sgml                           |  49 +++++
 doc/src/sgml/plpgsql.sgml                          |  91 ++++----
 doc/src/sgml/plpython.sgml                         |  39 ++++
 doc/src/sgml/pltcl.sgml                            |  41 ++++
 doc/src/sgml/ref/call.sgml                         |   7 +
 doc/src/sgml/ref/create_procedure.sgml             |   7 +
 doc/src/sgml/ref/do.sgml                           |   7 +
 doc/src/sgml/spi.sgml                              | 177 +++++++++++++++
 src/backend/commands/functioncmds.c                |  45 +++-
 src/backend/executor/spi.c                         |  99 ++++++++-
 src/backend/tcop/utility.c                         |   6 +-
 src/backend/utils/mmgr/portalmem.c                 |  49 +++--
 src/include/commands/defrem.h                      |   4 +-
 src/include/executor/spi.h                         |   7 +
 src/include/executor/spi_priv.h                    |   4 +
 src/include/nodes/nodes.h                          |   3 +-
 src/include/nodes/parsenodes.h                     |   7 +
 src/include/utils/portal.h                         |   1 +
 src/pl/plperl/GNUmakefile                          |   2 +-
 src/pl/plperl/SPI.xs                               |  10 +
 src/pl/plperl/expected/plperl_transaction.out      | 132 +++++++++++
 src/pl/plperl/plperl.c                             |  59 ++++-
 src/pl/plperl/plperl.h                             |   2 +
 src/pl/plperl/sql/plperl_transaction.sql           | 122 +++++++++++
 src/pl/plpgsql/src/Makefile                        |   2 +-
 .../plpgsql/src/expected/plpgsql_transaction.out   | 241 +++++++++++++++++++++
 src/pl/plpgsql/src/pl_exec.c                       |  66 +++++-
 src/pl/plpgsql/src/pl_funcs.c                      |  44 ++++
 src/pl/plpgsql/src/pl_gram.y                       |  34 +++
 src/pl/plpgsql/src/pl_handler.c                    |  11 +-
 src/pl/plpgsql/src/pl_scanner.c                    |   2 +
 src/pl/plpgsql/src/plpgsql.h                       |  22 +-
 src/pl/plpgsql/src/sql/plpgsql_transaction.sql     | 215 ++++++++++++++++++
 src/pl/plpython/Makefile                           |   1 +
 src/pl/plpython/expected/plpython_test.out         |   4 +-
 src/pl/plpython/expected/plpython_transaction.out  | 144 ++++++++++++
 src/pl/plpython/plpy_main.c                        |  11 +-
 src/pl/plpython/plpy_plpymodule.c                  |  39 ++++
 src/pl/plpython/sql/plpython_transaction.sql       | 117 ++++++++++
 src/pl/tcl/Makefile                                |   2 +-
 src/pl/tcl/expected/pltcl_transaction.out          | 100 +++++++++
 src/pl/tcl/pltcl.c                                 |  95 +++++++-
 src/pl/tcl/sql/pltcl_transaction.sql               |  98 +++++++++
 43 files changed, 2126 insertions(+), 92 deletions(-)
 create mode 100644 src/pl/plperl/expected/plperl_transaction.out
 create mode 100644 src/pl/plperl/sql/plperl_transaction.sql
 create mode 100644 src/pl/plpgsql/src/expected/plpgsql_transaction.out
 create mode 100644 src/pl/plpgsql/src/sql/plpgsql_transaction.sql
 create mode 100644 src/pl/plpython/expected/plpython_transaction.out
 create mode 100644 src/pl/plpython/sql/plpython_transaction.sql
 create mode 100644 src/pl/tcl/expected/pltcl_transaction.out
 create mode 100644 src/pl/tcl/sql/pltcl_transaction.sql

diff --git a/doc/src/sgml/plperl.sgml b/doc/src/sgml/plperl.sgml
index 100162dead..9acd41310f 100644
--- a/doc/src/sgml/plperl.sgml
+++ b/doc/src/sgml/plperl.sgml
@@ -661,6 +661,55 @@ <title>Database Access from PL/Perl</title>
     </para>
     </listitem>
     </varlistentry>
+
+    <varlistentry>
+     <term>
+      <literal><function>spi_commit()</function></literal>
+      <indexterm>
+       <primary>spi_commit</primary>
+       <secondary>in PL/Perl</secondary>
+     </indexterm>
+     </term>
+     <term>
+      <literal><function>spi_rollback()</function></literal>
+      <indexterm>
+       <primary>spi_rollback</primary>
+       <secondary>in PL/Perl</secondary>
+      </indexterm>
+     </term>
+     <listitem>
+      <para>
+       Commit or roll back the current transaction.  This can only be called
+       in a procedure or anonymous code block (<command>DO</command> command)
+       called from the top level.  (Note that it is not possible to run the
+       SQL commands <command>COMMIT</command> or <command>ROLLBACK</command>
+       via <function>spi_exec_query</function> or similar.  It has to be done
+       using these functions.)  After a transaction is ended, a new
+       transaction is automatically started, so there is no separate function
+       for that.
+      </para>
+
+      <para>
+       Here is an example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+CALL transaction_test1();
+</programlisting>
+      </para>
+     </listitem>
+    </varlistentry>
    </variablelist>
  </sect2>
 
diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml
index 7d23ed437e..00441af810 100644
--- a/doc/src/sgml/plpgsql.sgml
+++ b/doc/src/sgml/plpgsql.sgml
@@ -3449,6 +3449,48 @@ <title>Looping Through a Cursor's Result</title>
 
   </sect1>
 
+  <sect1 id="plpgsql-transactions">
+   <title>Transaction Management</title>
+
+   <para>
+    In procedures invoked by the <command>CALL</command> command from the top
+    level as well as in anonymous code blocks (<command>DO</command> command)
+    called from the top level, it is possible to end transactions using the
+    commands <command>COMMIT</command> and <command>ROLLBACK</command>.  A new
+    transaction is started automatically after a transaction is ended using
+    these commands, so there is no separate <command>START
+    TRANSACTION</command> command.  (Note that <command>BEGIN</command> and
+    <command>END</command> have different meanings in PL/pgSQL.)
+   </para>
+
+   <para>
+    Here is a simple example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+CALL transaction_test1();
+</programlisting>
+   </para>
+
+   <para>
+    Transactions cannot be ended inside loops through query results or inside
+    blocks with exception handlers.
+   </para>
+  </sect1>
+
   <sect1 id="plpgsql-errors-and-messages">
    <title>Errors and Messages</title>
 
@@ -5432,14 +5474,13 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
 <programlisting>
 CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id IN INTEGER) IS
     a_running_job_count INTEGER;
-    PRAGMA AUTONOMOUS_TRANSACTION; -- <co id="co.plpgsql-porting-pragma"/>
 BEGIN
-    LOCK TABLE cs_jobs IN EXCLUSIVE MODE; -- <co id="co.plpgsql-porting-locktable"/>
+    LOCK TABLE cs_jobs IN EXCLUSIVE MODE;
 
     SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL;
 
     IF a_running_job_count &gt; 0 THEN
-        COMMIT; -- free lock <co id="co.plpgsql-porting-commit"/>
+        COMMIT; -- free lock
         raise_application_error(-20000,
                  'Unable to create a new job: a job is currently running.');
     END IF;
@@ -5459,45 +5500,11 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
 </programlisting>
    </para>
 
-   <para>
-    Procedures like this can easily be converted into <productname>PostgreSQL</productname>
-    functions returning <type>void</type>. This procedure in
-    particular is interesting because it can teach us some things:
-
-    <calloutlist>
-     <callout arearefs="co.plpgsql-porting-pragma">
-      <para>
-       There is no <literal>PRAGMA</literal> statement in <productname>PostgreSQL</productname>.
-      </para>
-     </callout>
-
-     <callout arearefs="co.plpgsql-porting-locktable">
-      <para>
-       If you do a <command>LOCK TABLE</command> in <application>PL/pgSQL</application>,
-       the lock will not be released until the calling transaction is
-       finished.
-      </para>
-     </callout>
-
-     <callout arearefs="co.plpgsql-porting-commit">
-      <para>
-       You cannot issue <command>COMMIT</command> in a
-       <application>PL/pgSQL</application> function.  The function is
-       running within some outer transaction and so <command>COMMIT</command>
-       would imply terminating the function's execution.  However, in
-       this particular case it is not necessary anyway, because the lock
-       obtained by the <command>LOCK TABLE</command> will be released when
-       we raise an error.
-      </para>
-     </callout>
-    </calloutlist>
-   </para>
-
    <para>
     This is how we could port this procedure to <application>PL/pgSQL</application>:
 
 <programlisting>
-CREATE OR REPLACE FUNCTION cs_create_job(v_job_id integer) RETURNS void AS $$
+CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id integer) AS $$
 DECLARE
     a_running_job_count integer;
 BEGIN
@@ -5506,6 +5513,7 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
     SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL;
 
     IF a_running_job_count &gt; 0 THEN
+        COMMIT; -- free lock
         RAISE EXCEPTION 'Unable to create a new job: a job is currently running'; -- <co id="co.plpgsql-porting-raise"/>
     END IF;
 
@@ -5518,6 +5526,7 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
         WHEN unique_violation THEN -- <co id="co.plpgsql-porting-exception"/>
             -- don't worry if it already exists
     END;
+    COMMIT;
 END;
 $$ LANGUAGE plpgsql;
 </programlisting>
@@ -5541,12 +5550,6 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
       </para>
      </callout>
     </calloutlist>
-
-    The main functional difference between this procedure and the
-    Oracle equivalent is that the exclusive lock on the <literal>cs_jobs</literal>
-    table will be held until the calling transaction completes.  Also, if
-    the caller later aborts (for example due to an error), the effects of
-    this procedure will be rolled back.
    </para>
    </example>
   </sect2>
diff --git a/doc/src/sgml/plpython.sgml b/doc/src/sgml/plpython.sgml
index 0dbeee1fa2..8641038abe 100644
--- a/doc/src/sgml/plpython.sgml
+++ b/doc/src/sgml/plpython.sgml
@@ -1370,6 +1370,45 @@ <title>Older Python Versions</title>
   </sect2>
  </sect1>
 
+ <sect1 id="plpython-transactions">
+  <title>Transaction Management</title>
+
+  <para>
+   In a procedure called from the top level or an anonymous code block
+   (<command>DO</command> command) called from the top level it is possible to
+   control transactions.  To commit the current transaction, call
+   <literal>plpy.commit()</literal>.  To roll back the current transaction,
+   call <literal>plpy.rollback()</literal>.  (Note that it is not possible to
+   run the SQL commands <command>COMMIT</command> or
+   <command>ROLLBACK</command> via <function>plpy.execute</function> or
+   similar.  It has to be done using these functions.)  After a transaction is
+   ended, a new transaction is automatically started, so there is no separate
+   function for that.
+  </para>
+
+  <para>
+   Here is an example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+CALL transaction_test1();
+</programlisting>
+  </para>
+
+  <para>
+   Transactions cannot be ended when an explicit subtransaction is active.
+  </para>
+ </sect1>
+
  <sect1 id="plpython-util">
   <title>Utility Functions</title>
   <para>
diff --git a/doc/src/sgml/pltcl.sgml b/doc/src/sgml/pltcl.sgml
index 8018783b0a..a834ab8862 100644
--- a/doc/src/sgml/pltcl.sgml
+++ b/doc/src/sgml/pltcl.sgml
@@ -1002,6 +1002,47 @@ <title>Explicit Subtransactions in PL/Tcl</title>
     </para>
    </sect1>
 
+   <sect1 id="pltcl-transactions">
+    <title>Transaction Management</title>
+
+    <para>
+     In a procedure called from the top level or an anonymous code block
+     (<command>DO</command> command) called from the top level it is possible
+     to control transactions.  To commit the current transaction, call the
+     <literal>commit</literal> command.  To roll back the current transaction,
+     call the <literal>rollback</literal> command.  (Note that it is not
+     possible to run the SQL commands <command>COMMIT</command> or
+     <command>ROLLBACK</command> via <function>spi_exec</function> or similar.
+     It has to be done using these functions.)  After a transaction is ended,
+     a new transaction is automatically started, so there is no separate
+     command for that.
+    </para>
+
+    <para>
+     Here is an example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i &lt; 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+
+CALL transaction_test1();
+</programlisting>
+    </para>
+
+    <para>
+     Transactions cannot be ended when an explicit subtransaction is active.
+    </para>
+   </sect1>
+
    <sect1 id="pltcl-config">
     <title>PL/Tcl Configuration</title>
 
diff --git a/doc/src/sgml/ref/call.sgml b/doc/src/sgml/ref/call.sgml
index 2741d8d15e..03da4518ee 100644
--- a/doc/src/sgml/ref/call.sgml
+++ b/doc/src/sgml/ref/call.sgml
@@ -70,6 +70,13 @@ <title>Notes</title>
   <para>
    To call a function (not a procedure), use <command>SELECT</command> instead.
   </para>
+
+  <para>
+   If <command>CALL</command> is executed in a transaction block, then the
+   called procedure cannot execute transaction control statements.
+   Transaction control statements are only allowed if <command>CALL</command>
+   is executed in its own transaction.
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_procedure.sgml b/doc/src/sgml/ref/create_procedure.sgml
index d712043824..bbf8b03d04 100644
--- a/doc/src/sgml/ref/create_procedure.sgml
+++ b/doc/src/sgml/ref/create_procedure.sgml
@@ -228,6 +228,13 @@ <title>Parameters</title>
        procedure exit, unless the current transaction is rolled back.
       </para>
 
+      <para>
+       If a <literal>SET</literal> clause is attached to a procedure, then
+       that procedure cannot execute transaction control statements (for
+       example, <command>COMMIT</command> and <command>ROLLBACK</command>,
+       depending on the language).
+      </para>
+
       <para>
        See <xref linkend="sql-set"/> and
        <xref linkend="runtime-config"/>
diff --git a/doc/src/sgml/ref/do.sgml b/doc/src/sgml/ref/do.sgml
index 061218b135..b9a6f9a6fd 100644
--- a/doc/src/sgml/ref/do.sgml
+++ b/doc/src/sgml/ref/do.sgml
@@ -91,6 +91,13 @@ <title>Notes</title>
    This is the same privilege requirement as for creating a function
    in the language.
   </para>
+
+  <para>
+   If <command>DO</command> is executed in a transaction block, then the
+   procedure code cannot execute transaction control statements.  Transaction
+   control statements are only allowed if <command>DO</command> is executed in
+   its own transaction.
+  </para>
  </refsect1>
 
  <refsect1 id="sql-do-examples">
diff --git a/doc/src/sgml/spi.sgml b/doc/src/sgml/spi.sgml
index 350f0863e9..10448922b1 100644
--- a/doc/src/sgml/spi.sgml
+++ b/doc/src/sgml/spi.sgml
@@ -64,6 +64,7 @@ <title>Interface Functions</title>
 
  <refentry id="spi-spi-connect">
   <indexterm><primary>SPI_connect</primary></indexterm>
+  <indexterm><primary>SPI_connect_ext</primary></indexterm>
 
   <refmeta>
    <refentrytitle>SPI_connect</refentrytitle>
@@ -72,12 +73,17 @@ <title>Interface Functions</title>
 
   <refnamediv>
    <refname>SPI_connect</refname>
+   <refname>SPI_connect_ext</refname>
    <refpurpose>connect a procedure to the SPI manager</refpurpose>
  </refnamediv>
 
  <refsynopsisdiv>
 <synopsis>
 int SPI_connect(void)
+</synopsis>
+
+ <synopsis>
+int SPI_connect_ext(int <parameter>options</parameter>)
 </synopsis>
  </refsynopsisdiv>
 
@@ -90,6 +96,31 @@ <title>Description</title>
    function if you want to execute commands through SPI.  Some utility
    SPI functions can be called from unconnected procedures.
   </para>
+
+  <para>
+   <function>SPI_connect_ext</function> does the same but has an argument that
+   allows passing option flags.  Currently, the following option values are
+   available:
+   <variablelist>
+    <varlistentry>
+     <term><symbol>SPI_OPT_NONATOMIC</symbol></term>
+     <listitem>
+      <para>
+       Sets the SPI connection to be <firstterm>nonatomic</firstterm>, which
+       means that transaction control calls <function>SPI_commit</function>,
+       <function>SPI_rollback</function>, and
+       <function>SPI_start_transaction</function> are allowed.  Otherwise,
+       calling these functions will result in an immediate error.
+      </para>
+     </listitem>
+    </varlistentry>
+   </variablelist>
+  </para>
+
+  <para>
+   <literal>SPI_connect()</literal> is equivalent to
+   <literal>SPI_connect_ext(0)</literal>.
+  </para>
  </refsect1>
 
  <refsect1>
@@ -4325,6 +4356,152 @@ <title>Return Value</title>
 
  </sect1>
 
+ <sect1 id="spi-transaction">
+  <title>Transaction Management</title>
+
+  <para>
+   It is not possible to run transaction control commands such
+   as <command>COMMIT</command> and <command>ROLLBACK</command> through SPI
+   functions such as <function>SPI_execute</function>.  There are, however,
+   separate interface functions that allow transaction control through SPI.
+  </para>
+
+  <para>
+   It is not generally safe and sensible to start and end transactions in
+   arbitrary user-defined SQL-callable functions without taking into account
+   the context in which they are called.  For example, a transaction boundary
+   in the middle of a function that is part of a complex SQL expression that
+   is part of some SQL command will probably result in obscure internal errors
+   or crashes.  The interface functions presented here are primarily intended
+   to be used by procedural language implementations to support transaction
+   management in procedures that are invoked by the <command>CALL</command>
+   command, taking the context of the <command>CALL</command> invocation into
+   account.  SPI procedures implemented in C can implement the same logic, but
+   the details of that are beyond the scope of this documentation.
+  </para>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-commit">
+ <indexterm><primary>SPI_commit</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_commit</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_commit</refname>
+  <refpurpose>commit the current transaction</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+void SPI_commit(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_commit</function> commits the current transaction.  It is
+   approximately equivalent to running the SQL
+   command <command>COMMIT</command>.  After a transaction is committed, a new
+   transaction has to be started
+   using <function>SPI_start_transaction</function> before further database
+   actions can be executed.
+  </para>
+
+  <para>
+   This function can only be executed if the SPI connection has been set as
+   nonatomic in the call to <function>SPI_connect_ext</function>.
+  </para>
+ </refsect1>
+</refentry>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-rollback">
+ <indexterm><primary>SPI_rollback</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_rollback</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_rollback</refname>
+  <refpurpose>abort the current transaction</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+void SPI_rollback(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_rollback</function> rolls back the current transaction.  It
+   is approximately equivalent to running the SQL
+   command <command>ROLLBACK</command>.  After a transaction is rolled back, a
+   new transaction has to be started
+   using <function>SPI_start_transaction</function> before further database
+   actions can be executed.
+  </para>
+
+  <para>
+   This function can only be executed if the SPI connection has been set as
+   nonatomic in the call to <function>SPI_connect_ext</function>.
+  </para>
+ </refsect1>
+</refentry>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-start-transaction">
+ <indexterm><primary>SPI_start_transaction</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_start_transaction</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_start_transaction</refname>
+  <refpurpose>start a new transaction</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+void SPI_start_transaction(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_start_transaction</function> starts a new transaction.  It
+   can only be called after <function>SPI_commit</function>
+   or <function>SPI_rollback</function>, as there is no transaction active at
+   that point.  Normally, when an SPI procedure is called, there is already a
+   transaction active, so attempting to start another one before closing out
+   the current one will result in an error.
+  </para>
+
+  <para>
+   This function can only be executed if the SPI connection has been set as
+   nonatomic in the call to <function>SPI_connect_ext</function>.
+  </para>
+ </refsect1>
+</refentry>
+
+ </sect1>
+
  <sect1 id="spi-visibility">
   <title>Visibility of Data Changes</title>
 
diff --git a/src/backend/commands/functioncmds.c b/src/backend/commands/functioncmds.c
index 12ab33f418..9a33d33dcb 100644
--- a/src/backend/commands/functioncmds.c
+++ b/src/backend/commands/functioncmds.c
@@ -65,6 +65,7 @@
 #include "utils/fmgroids.h"
 #include "utils/guc.h"
 #include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/rel.h"
 #include "utils/syscache.h"
 #include "utils/tqual.h"
@@ -2138,7 +2139,7 @@ IsThereFunctionInNamespace(const char *proname, int pronargs,
  *		Execute inline procedural-language code
  */
 void
-ExecuteDoStmt(DoStmt *stmt)
+ExecuteDoStmt(DoStmt *stmt, bool atomic)
 {
 	InlineCodeBlock *codeblock = makeNode(InlineCodeBlock);
 	ListCell   *arg;
@@ -2200,6 +2201,7 @@ ExecuteDoStmt(DoStmt *stmt)
 	codeblock->langOid = HeapTupleGetOid(languageTuple);
 	languageStruct = (Form_pg_language) GETSTRUCT(languageTuple);
 	codeblock->langIsTrusted = languageStruct->lanpltrusted;
+	codeblock->atomic = atomic;
 
 	if (languageStruct->lanpltrusted)
 	{
@@ -2236,9 +2238,28 @@ ExecuteDoStmt(DoStmt *stmt)
 
 /*
  * Execute CALL statement
+ *
+ * Inside a top-level CALL statement, transaction-terminating commands such as
+ * COMMIT or a PL-specific equivalent are allowed.  The terminology in the SQL
+ * standard is that CALL establishes a non-atomic execution context.  Most
+ * other commands establish an atomic execution context, in which transaction
+ * control actions are not allowed.  If there are nested executions of CALL,
+ * we want to track the execution context recursively, so that the nested
+ * CALLs can also do transaction control.  Note, however, that for example in
+ * CALL -> SELECT -> CALL, the second call cannot do transaction control,
+ * because the SELECT in between establishes an atomic execution context.
+ *
+ * So when ExecuteCallStmt() is called from the top level, we pass in atomic =
+ * false (recall that that means transactions = yes).  We then create a
+ * CallContext node with content atomic = false, which is passed in the
+ * fcinfo->context field to the procedure invocation.  The language
+ * implementation should then take appropriate measures to allow or prevent
+ * transaction commands based on that information, e.g., call
+ * SPI_set_nonatomic().  The language should also pass on the atomic flag to
+ * any recursive invocations to CALL.
  */
 void
-ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
+ExecuteCallStmt(ParseState *pstate, CallStmt *stmt, bool atomic)
 {
 	List	   *targs;
 	ListCell   *lc;
@@ -2249,6 +2270,8 @@ ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
 	AclResult   aclresult;
 	FmgrInfo	flinfo;
 	FunctionCallInfoData fcinfo;
+	CallContext *callcontext;
+	HeapTuple	tp;
 
 	targs = NIL;
 	foreach(lc, stmt->funccall->args)
@@ -2284,8 +2307,24 @@ ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
 							   FUNC_MAX_ARGS,
 							   FUNC_MAX_ARGS)));
 
+	callcontext = makeNode(CallContext);
+	callcontext->atomic = atomic;
+
+	/*
+	 * If proconfig is set we can't allow transaction commands because of the
+	 * way the GUC stacking works: The transaction boundary would have to pop
+	 * the proconfig setting off the stack.  That restriction could be lifted
+	 * by redesigning the GUC nesting mechanism a bit.
+	 */
+	tp = SearchSysCache1(PROCOID, ObjectIdGetDatum(fexpr->funcid));
+	if (!HeapTupleIsValid(tp))
+		elog(ERROR, "cache lookup failed for function %u", fexpr->funcid);
+	if (!heap_attisnull(tp, Anum_pg_proc_proconfig))
+		callcontext->atomic = true;
+	ReleaseSysCache(tp);
+
 	fmgr_info(fexpr->funcid, &flinfo);
-	InitFunctionCallInfoData(fcinfo, &flinfo, nargs, fexpr->inputcollid, NULL, NULL);
+	InitFunctionCallInfoData(fcinfo, &flinfo, nargs, fexpr->inputcollid, (Node *) callcontext, NULL);
 
 	i = 0;
 	foreach (lc, fexpr->args)
diff --git a/src/backend/executor/spi.c b/src/backend/executor/spi.c
index 4d9b51b947..2e0729d675 100644
--- a/src/backend/executor/spi.c
+++ b/src/backend/executor/spi.c
@@ -82,6 +82,12 @@ static bool _SPI_checktuples(void);
 
 int
 SPI_connect(void)
+{
+	return SPI_connect_ext(0);
+}
+
+int
+SPI_connect_ext(int options)
 {
 	int			newdepth;
 
@@ -92,7 +98,7 @@ SPI_connect(void)
 			elog(ERROR, "SPI stack corrupted");
 		newdepth = 16;
 		_SPI_stack = (_SPI_connection *)
-			MemoryContextAlloc(TopTransactionContext,
+			MemoryContextAlloc(TopMemoryContext,
 							   newdepth * sizeof(_SPI_connection));
 		_SPI_stack_depth = newdepth;
 	}
@@ -124,19 +130,25 @@ SPI_connect(void)
 	_SPI_current->execCxt = NULL;
 	_SPI_current->connectSubid = GetCurrentSubTransactionId();
 	_SPI_current->queryEnv = NULL;
+	_SPI_current->atomic = (options & SPI_OPT_NONATOMIC ? false : true);
+	_SPI_current->internal_xact = false;
 
 	/*
 	 * Create memory contexts for this procedure
 	 *
-	 * XXX it would be better to use PortalContext as the parent context, but
-	 * we may not be inside a portal (consider deferred-trigger execution).
-	 * Perhaps CurTransactionContext would do?	For now it doesn't matter
-	 * because we clean up explicitly in AtEOSubXact_SPI().
+	 * In atomic contexts (the normal case), we use TopTransactionContext,
+	 * otherwise PortalContext, so that it lives across transaction
+	 * boundaries.
+	 *
+	 * XXX It could be better to use PortalContext as the parent context in
+	 * all cases, but we may not be inside a portal (consider deferred-trigger
+	 * execution).  Perhaps CurTransactionContext could be an option?  For now
+	 * it doesn't matter because we clean up explicitly in AtEOSubXact_SPI().
 	 */
-	_SPI_current->procCxt = AllocSetContextCreate(TopTransactionContext,
+	_SPI_current->procCxt = AllocSetContextCreate(_SPI_current->atomic ? TopTransactionContext : PortalContext,
 												  "SPI Proc",
 												  ALLOCSET_DEFAULT_SIZES);
-	_SPI_current->execCxt = AllocSetContextCreate(TopTransactionContext,
+	_SPI_current->execCxt = AllocSetContextCreate(_SPI_current->atomic ? TopTransactionContext : _SPI_current->procCxt,
 												  "SPI Exec",
 												  ALLOCSET_DEFAULT_SIZES);
 	/* ... and switch to procedure's context */
@@ -181,12 +193,82 @@ SPI_finish(void)
 	return SPI_OK_FINISH;
 }
 
+void
+SPI_start_transaction(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	StartTransactionCommand();
+	MemoryContextSwitchTo(oldcontext);
+}
+
+void
+SPI_commit(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	if (_SPI_current->atomic)
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("invalid transaction termination")));
+
+	/*
+	 * This restriction is required by PLs implemented on top of SPI.  They
+	 * use subtransactions to establish exception blocks that are supposed to
+	 * be rolled back together if there is an error.  Terminating the
+	 * top-level transaction in such a block violates that idea.  A future PL
+	 * implementation might have different ideas about this, in which case
+	 * this restriction would have to be refined or the check possibly be
+	 * moved out of SPI into the PLs.
+	 */
+	if (IsSubTransaction())
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("cannot commit while a subtransaction is active")));
+
+	_SPI_current->internal_xact = true;
+
+	if (ActiveSnapshotSet())
+		PopActiveSnapshot();
+	CommitTransactionCommand();
+	MemoryContextSwitchTo(oldcontext);
+
+	_SPI_current->internal_xact = false;
+}
+
+void
+SPI_rollback(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	if (_SPI_current->atomic)
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("invalid transaction termination")));
+
+	/* see under SPI_commit() */
+	if (IsSubTransaction())
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("cannot roll back while a subtransaction is active")));
+
+	_SPI_current->internal_xact = true;
+
+	AbortCurrentTransaction();
+	MemoryContextSwitchTo(oldcontext);
+
+	_SPI_current->internal_xact = false;
+}
+
 /*
  * Clean up SPI state at transaction commit or abort.
  */
 void
 AtEOXact_SPI(bool isCommit)
 {
+	if (_SPI_current && _SPI_current->internal_xact)
+		return;
+
 	/*
 	 * Note that memory contexts belonging to SPI stack entries will be freed
 	 * automatically, so we can ignore them here.  We just need to restore our
@@ -224,6 +306,9 @@ AtEOSubXact_SPI(bool isCommit, SubTransactionId mySubid)
 		if (connection->connectSubid != mySubid)
 			break;				/* couldn't be any underneath it either */
 
+		if (connection->internal_xact)
+			break;
+
 		found = true;
 
 		/*
diff --git a/src/backend/tcop/utility.c b/src/backend/tcop/utility.c
index ec98a612ec..0b8cfd0da4 100644
--- a/src/backend/tcop/utility.c
+++ b/src/backend/tcop/utility.c
@@ -529,7 +529,8 @@ standard_ProcessUtility(PlannedStmt *pstmt,
 			break;
 
 		case T_DoStmt:
-			ExecuteDoStmt((DoStmt *) parsetree);
+			ExecuteDoStmt((DoStmt *) parsetree,
+						  (context != PROCESS_UTILITY_TOPLEVEL || IsTransactionBlock()));
 			break;
 
 		case T_CreateTableSpaceStmt:
@@ -658,7 +659,8 @@ standard_ProcessUtility(PlannedStmt *pstmt,
 			break;
 
 		case T_CallStmt:
-			ExecuteCallStmt(pstate, castNode(CallStmt, parsetree));
+			ExecuteCallStmt(pstate, castNode(CallStmt, parsetree),
+							(context != PROCESS_UTILITY_TOPLEVEL || IsTransactionBlock()));
 			break;
 
 		case T_ClusterStmt:
diff --git a/src/backend/utils/mmgr/portalmem.c b/src/backend/utils/mmgr/portalmem.c
index c93c37d74a..2489a94d77 100644
--- a/src/backend/utils/mmgr/portalmem.c
+++ b/src/backend/utils/mmgr/portalmem.c
@@ -736,11 +736,8 @@ PreCommit_Portals(bool isPrepare)
 /*
  * Abort processing for portals.
  *
- * At this point we reset "active" status and run the cleanup hook if
- * present, but we can't release the portal's memory until the cleanup call.
- *
- * The reason we need to reset active is so that we can replace the unnamed
- * portal, else we'll fail to execute ROLLBACK when it arrives.
+ * At this point we run the cleanup hook if present, but we can't release the
+ * portal's memory until the cleanup call.
  */
 void
 AtAbort_Portals(void)
@@ -754,17 +751,6 @@ AtAbort_Portals(void)
 	{
 		Portal		portal = hentry->portal;
 
-		/*
-		 * See similar code in AtSubAbort_Portals().  This would fire if code
-		 * orchestrating multiple top-level transactions within a portal, such
-		 * as VACUUM, caught errors and continued under the same portal with a
-		 * fresh transaction.  No part of core PostgreSQL functions that way.
-		 * XXX Such code would wish the portal to remain ACTIVE, as in
-		 * PreCommit_Portals().
-		 */
-		if (portal->status == PORTAL_ACTIVE)
-			MarkPortalFailed(portal);
-
 		/*
 		 * Do nothing else to cursors held over from a previous transaction.
 		 */
@@ -804,9 +790,10 @@ AtAbort_Portals(void)
 		 * Although we can't delete the portal data structure proper, we can
 		 * release any memory in subsidiary contexts, such as executor state.
 		 * The cleanup hook was the last thing that might have needed data
-		 * there.
+		 * there.  But leave active portals alone.
 		 */
-		MemoryContextDeleteChildren(PortalGetHeapMemory(portal));
+		if (portal->status != PORTAL_ACTIVE)
+			MemoryContextDeleteChildren(PortalGetHeapMemory(portal));
 	}
 }
 
@@ -826,6 +813,13 @@ AtCleanup_Portals(void)
 	{
 		Portal		portal = hentry->portal;
 
+		/*
+		 * Do not touch active portals --- this can only happen in the case of
+		 * a multi-transaction command.
+		 */
+		if (portal->status == PORTAL_ACTIVE)
+			continue;
+
 		/* Do nothing to cursors held over from a previous transaction */
 		if (portal->createSubid == InvalidSubTransactionId)
 		{
@@ -1155,3 +1149,22 @@ ThereAreNoReadyPortals(void)
 
 	return true;
 }
+
+bool
+ThereArePinnedPortals(void)
+{
+	HASH_SEQ_STATUS status;
+	PortalHashEnt *hentry;
+
+	hash_seq_init(&status, PortalHashTable);
+
+	while ((hentry = (PortalHashEnt *) hash_seq_search(&status)) != NULL)
+	{
+		Portal		portal = hentry->portal;
+
+		if (portal->portalPinned)
+			return true;
+	}
+
+	return false;
+}
diff --git a/src/include/commands/defrem.h b/src/include/commands/defrem.h
index 1f18cad963..e0021878fb 100644
--- a/src/include/commands/defrem.h
+++ b/src/include/commands/defrem.h
@@ -58,8 +58,8 @@ extern ObjectAddress CreateTransform(CreateTransformStmt *stmt);
 extern void DropTransformById(Oid transformOid);
 extern void IsThereFunctionInNamespace(const char *proname, int pronargs,
 						   oidvector *proargtypes, Oid nspOid);
-extern void ExecuteDoStmt(DoStmt *stmt);
-extern void ExecuteCallStmt(ParseState *pstate, CallStmt *stmt);
+extern void ExecuteDoStmt(DoStmt *stmt, bool atomic);
+extern void ExecuteCallStmt(ParseState *pstate, CallStmt *stmt, bool atomic);
 extern Oid	get_cast_oid(Oid sourcetypeid, Oid targettypeid, bool missing_ok);
 extern Oid	get_transform_oid(Oid type_id, Oid lang_id, bool missing_ok);
 extern void interpret_function_parameter_list(ParseState *pstate,
diff --git a/src/include/executor/spi.h b/src/include/executor/spi.h
index 43580c5158..e5bdaecc4e 100644
--- a/src/include/executor/spi.h
+++ b/src/include/executor/spi.h
@@ -65,6 +65,8 @@ typedef struct _SPI_plan *SPIPlanPtr;
 #define SPI_OK_REL_UNREGISTER	16
 #define SPI_OK_TD_REGISTER		17
 
+#define SPI_OPT_NONATOMIC		(1 << 0)
+
 /* These used to be functions, now just no-ops for backwards compatibility */
 #define SPI_push()	((void) 0)
 #define SPI_pop()	((void) 0)
@@ -78,6 +80,7 @@ extern PGDLLIMPORT SPITupleTable *SPI_tuptable;
 extern PGDLLIMPORT int SPI_result;
 
 extern int	SPI_connect(void);
+extern int	SPI_connect_ext(int options);
 extern int	SPI_finish(void);
 extern int	SPI_execute(const char *src, bool read_only, long tcount);
 extern int SPI_execute_plan(SPIPlanPtr plan, Datum *Values, const char *Nulls,
@@ -156,6 +159,10 @@ extern int	SPI_register_relation(EphemeralNamedRelation enr);
 extern int	SPI_unregister_relation(const char *name);
 extern int	SPI_register_trigger_data(TriggerData *tdata);
 
+extern void SPI_start_transaction(void);
+extern void SPI_commit(void);
+extern void SPI_rollback(void);
+
 extern void AtEOXact_SPI(bool isCommit);
 extern void AtEOSubXact_SPI(bool isCommit, SubTransactionId mySubid);
 
diff --git a/src/include/executor/spi_priv.h b/src/include/executor/spi_priv.h
index 64f8a450eb..263c8f1453 100644
--- a/src/include/executor/spi_priv.h
+++ b/src/include/executor/spi_priv.h
@@ -36,6 +36,10 @@ typedef struct
 	MemoryContext savedcxt;		/* context of SPI_connect's caller */
 	SubTransactionId connectSubid;	/* ID of connecting subtransaction */
 	QueryEnvironment *queryEnv; /* query environment setup for SPI level */
+
+	/* transaction management support */
+	bool		atomic;			/* atomic execution context, does not allow transactions */
+	bool		internal_xact;	/* SPI-managed transaction boundary, skip cleanup */
 } _SPI_connection;
 
 /*
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 2eb3d6d371..74b094a9c3 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -500,7 +500,8 @@ typedef enum NodeTag
 	T_FdwRoutine,				/* in foreign/fdwapi.h */
 	T_IndexAmRoutine,			/* in access/amapi.h */
 	T_TsmRoutine,				/* in access/tsmapi.h */
-	T_ForeignKeyCacheInfo		/* in utils/rel.h */
+	T_ForeignKeyCacheInfo,		/* in utils/rel.h */
+	T_CallContext				/* in nodes/parsenodes.h */
 } NodeTag;
 
 /*
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b72178efd1..ccc2fda662 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2803,6 +2803,7 @@ typedef struct InlineCodeBlock
 	char	   *source_text;	/* source text of anonymous code block */
 	Oid			langOid;		/* OID of selected language */
 	bool		langIsTrusted;	/* trusted property of the language */
+	bool		atomic;			/* atomic execution context */
 } InlineCodeBlock;
 
 /* ----------------------
@@ -2815,6 +2816,12 @@ typedef struct CallStmt
 	FuncCall   *funccall;
 } CallStmt;
 
+typedef struct CallContext
+{
+	NodeTag		type;
+	bool		atomic;
+} CallContext;
+
 /* ----------------------
  *		Alter Object Rename Statement
  * ----------------------
diff --git a/src/include/utils/portal.h b/src/include/utils/portal.h
index 3e7820b51c..41ca51dff9 100644
--- a/src/include/utils/portal.h
+++ b/src/include/utils/portal.h
@@ -237,5 +237,6 @@ extern PlannedStmt *PortalGetPrimaryStmt(Portal portal);
 extern void PortalCreateHoldStore(Portal portal);
 extern void PortalHashTableDeleteAll(void);
 extern bool ThereAreNoReadyPortals(void);
+extern bool ThereArePinnedPortals(void);
 
 #endif							/* PORTAL_H */
diff --git a/src/pl/plperl/GNUmakefile b/src/pl/plperl/GNUmakefile
index b829027d05..933abb47c4 100644
--- a/src/pl/plperl/GNUmakefile
+++ b/src/pl/plperl/GNUmakefile
@@ -55,7 +55,7 @@ endif # win32
 SHLIB_LINK = $(perl_embed_ldflags)
 
 REGRESS_OPTS = --dbname=$(PL_TESTDB) --load-extension=plperl  --load-extension=plperlu
-REGRESS = plperl plperl_lc plperl_trigger plperl_shared plperl_elog plperl_util plperl_init plperlu plperl_array plperl_call
+REGRESS = plperl plperl_lc plperl_trigger plperl_shared plperl_elog plperl_util plperl_init plperlu plperl_array plperl_call plperl_transaction
 # if Perl can support two interpreters in one backend,
 # test plperl-and-plperlu cases
 ifneq ($(PERL),)
diff --git a/src/pl/plperl/SPI.xs b/src/pl/plperl/SPI.xs
index d9e6f579d4..de5d812cbd 100644
--- a/src/pl/plperl/SPI.xs
+++ b/src/pl/plperl/SPI.xs
@@ -17,6 +17,7 @@
 #define PG_NEED_PERL_XSUB_H
 #include "plperl.h"
 #include "plperl_helpers.h"
+#include "executor/spi.h"
 
 
 MODULE = PostgreSQL::InServer::SPI PREFIX = spi_
@@ -152,6 +153,15 @@ spi_spi_cursor_close(sv)
 		plperl_spi_cursor_close(cursor);
 		pfree(cursor);
 
+void
+spi_spi_commit()
+	CODE:
+		plperl_spi_commit();
+
+void
+spi_spi_rollback()
+	CODE:
+		plperl_spi_rollback();
 
 BOOT:
     items = 0;  /* avoid 'unused variable' warning */
diff --git a/src/pl/plperl/expected/plperl_transaction.out b/src/pl/plperl/expected/plperl_transaction.out
new file mode 100644
index 0000000000..5ce33d9c7c
--- /dev/null
+++ b/src/pl/plperl/expected/plperl_transaction.out
@@ -0,0 +1,132 @@
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+DO
+LANGUAGE plperl
+$$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+return 1;
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination at line 5.
+CONTEXT:  PL/Perl function "transaction_test2"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query("CALL transaction_test1()");
+return 1;
+$$;
+SELECT transaction_test3();
+ERROR:  invalid transaction termination at line 5. at line 2.
+CONTEXT:  PL/Perl function "transaction_test3"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query('DO LANGUAGE plperl $x$ spi_commit(); $x$');
+return 1;
+$$;
+SELECT transaction_test4();
+ERROR:  invalid transaction termination at line 1. at line 2.
+CONTEXT:  PL/Perl function "transaction_test4"
+-- FIXME
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+TRUNCATE test1;
+DO LANGUAGE plperl $$
+my $sth = spi_query("SELECT * FROM test2 ORDER BY x");
+my $row;
+while (defined($row = spi_fetchrow($sth))) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES (" . $row->{x} . ")");
+    spi_commit();
+}
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+(1 row)
+
+-- FIXME
+-- rollback inside cursor loop
+TRUNCATE test1;
+DO LANGUAGE plperl $$
+my $sth = spi_query("SELECT * FROM test2 ORDER BY x");
+my $row;
+while (defined($row = spi_fetchrow($sth))) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES (" . $row->{x} . ")");
+    spi_rollback();
+}
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+DROP TABLE test1;
+DROP TABLE test2;
diff --git a/src/pl/plperl/plperl.c b/src/pl/plperl/plperl.c
index 41fd0ba421..b3f3b43f8d 100644
--- a/src/pl/plperl/plperl.c
+++ b/src/pl/plperl/plperl.c
@@ -1929,7 +1929,7 @@ plperl_inline_handler(PG_FUNCTION_ARGS)
 
 		current_call_data = &this_call_data;
 
-		if (SPI_connect() != SPI_OK_CONNECT)
+		if (SPI_connect_ext(codeblock->atomic ? 0 : SPI_OPT_NONATOMIC) != SPI_OK_CONNECT)
 			elog(ERROR, "could not connect to SPI manager");
 
 		select_perl_context(desc.lanpltrusted);
@@ -2396,13 +2396,18 @@ plperl_call_perl_event_trigger_func(plperl_proc_desc *desc,
 static Datum
 plperl_func_handler(PG_FUNCTION_ARGS)
 {
+	bool		nonatomic;
 	plperl_proc_desc *prodesc;
 	SV		   *perlret;
 	Datum		retval = 0;
 	ReturnSetInfo *rsi;
 	ErrorContextCallback pl_error_context;
 
-	if (SPI_connect() != SPI_OK_CONNECT)
+	nonatomic = fcinfo->context &&
+		IsA(fcinfo->context, CallContext) &&
+		!castNode(CallContext, fcinfo->context)->atomic;
+
+	if (SPI_connect_ext(nonatomic ? SPI_OPT_NONATOMIC : 0) != SPI_OK_CONNECT)
 		elog(ERROR, "could not connect to SPI manager");
 
 	prodesc = compile_plperl_function(fcinfo->flinfo->fn_oid, false, false);
@@ -3945,6 +3950,56 @@ plperl_spi_freeplan(char *query)
 	SPI_freeplan(plan);
 }
 
+void
+plperl_spi_commit(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	PG_TRY();
+	{
+		SPI_commit();
+		SPI_start_transaction();
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Punt the error to Perl */
+		croak_cstr(edata->message);
+	}
+	PG_END_TRY();
+}
+
+void
+plperl_spi_rollback(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	PG_TRY();
+	{
+		SPI_rollback();
+		SPI_start_transaction();
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Punt the error to Perl */
+		croak_cstr(edata->message);
+	}
+	PG_END_TRY();
+}
+
 /*
  * Implementation of plperl's elog() function
  *
diff --git a/src/pl/plperl/plperl.h b/src/pl/plperl/plperl.h
index 78366aac04..6fe7803088 100644
--- a/src/pl/plperl/plperl.h
+++ b/src/pl/plperl/plperl.h
@@ -125,6 +125,8 @@ HV		   *plperl_spi_exec_prepared(char *, HV *, int, SV **);
 SV		   *plperl_spi_query_prepared(char *, int, SV **);
 void		plperl_spi_freeplan(char *);
 void		plperl_spi_cursor_close(char *);
+void		plperl_spi_commit(void);
+void		plperl_spi_rollback(void);
 char	   *plperl_sv_to_literal(SV *, char *);
 void		plperl_util_elog(int level, SV *msg);
 
diff --git a/src/pl/plperl/sql/plperl_transaction.sql b/src/pl/plperl/sql/plperl_transaction.sql
new file mode 100644
index 0000000000..081e03f238
--- /dev/null
+++ b/src/pl/plperl/sql/plperl_transaction.sql
@@ -0,0 +1,122 @@
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+DO
+LANGUAGE plperl
+$$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+return 1;
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query("CALL transaction_test1()");
+return 1;
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query('DO LANGUAGE plperl $x$ spi_commit(); $x$');
+return 1;
+$$;
+
+SELECT transaction_test4();
+
+
+-- FIXME
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+
+TRUNCATE test1;
+
+DO LANGUAGE plperl $$
+my $sth = spi_query("SELECT * FROM test2 ORDER BY x");
+my $row;
+while (defined($row = spi_fetchrow($sth))) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES (" . $row->{x} . ")");
+    spi_commit();
+}
+$$;
+
+SELECT * FROM test1;
+
+
+-- FIXME
+-- rollback inside cursor loop
+TRUNCATE test1;
+
+DO LANGUAGE plperl $$
+my $sth = spi_query("SELECT * FROM test2 ORDER BY x");
+my $row;
+while (defined($row = spi_fetchrow($sth))) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES (" . $row->{x} . ")");
+    spi_rollback();
+}
+$$;
+
+SELECT * FROM test1;
+
+
+DROP TABLE test1;
+DROP TABLE test2;
diff --git a/src/pl/plpgsql/src/Makefile b/src/pl/plpgsql/src/Makefile
index 14a4d83584..91e1ada7ad 100644
--- a/src/pl/plpgsql/src/Makefile
+++ b/src/pl/plpgsql/src/Makefile
@@ -26,7 +26,7 @@ DATA = plpgsql.control plpgsql--1.0.sql plpgsql--unpackaged--1.0.sql
 
 REGRESS_OPTS = --dbname=$(PL_TESTDB)
 
-REGRESS = plpgsql_call plpgsql_control
+REGRESS = plpgsql_call plpgsql_control plpgsql_transaction
 
 all: all-lib
 
diff --git a/src/pl/plpgsql/src/expected/plpgsql_transaction.out b/src/pl/plpgsql/src/expected/plpgsql_transaction.out
new file mode 100644
index 0000000000..8ec22c646c
--- /dev/null
+++ b/src/pl/plpgsql/src/expected/plpgsql_transaction.out
@@ -0,0 +1,241 @@
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+DO
+LANGUAGE plpgsql
+$$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+-- transaction commands not allowed when called in transaction block
+START TRANSACTION;
+CALL transaction_test1();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function transaction_test1() line 6 at COMMIT
+COMMIT;
+START TRANSACTION;
+DO LANGUAGE plpgsql $$ BEGIN COMMIT; END $$;
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function inline_code_block line 1 at COMMIT
+COMMIT;
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+    RETURN 1;
+END
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function transaction_test2() line 6 at COMMIT
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    CALL transaction_test1();
+    RETURN 1;
+END;
+$$;
+SELECT transaction_test3();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function transaction_test1() line 6 at COMMIT
+SQL statement "CALL transaction_test1()"
+PL/pgSQL function transaction_test3() line 3 at SQL statement
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    EXECUTE 'DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$';
+    RETURN 1;
+END;
+$$;
+SELECT transaction_test4();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function inline_code_block line 1 at COMMIT
+SQL statement "DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$"
+PL/pgSQL function transaction_test4() line 3 at EXECUTE
+-- proconfig settings currently disallow transaction statements
+CREATE PROCEDURE transaction_test5()
+LANGUAGE plpgsql
+SET work_mem = 555
+AS $$
+BEGIN
+    COMMIT;
+END;
+$$;
+CALL transaction_test5();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function transaction_test5() line 3 at COMMIT
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+TRUNCATE test1;
+DO LANGUAGE plpgsql $$
+DECLARE
+    r RECORD;
+BEGIN
+    FOR r IN SELECT * FROM test2 ORDER BY x LOOP
+        INSERT INTO test1 (a) VALUES (r.x);
+        COMMIT;
+    END LOOP;
+END;
+$$;
+ERROR:  committing inside a cursor loop is not supported
+CONTEXT:  PL/pgSQL function inline_code_block line 7 at COMMIT
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- rollback inside cursor loop
+TRUNCATE test1;
+DO LANGUAGE plpgsql $$
+DECLARE
+    r RECORD;
+BEGIN
+    FOR r IN SELECT * FROM test2 ORDER BY x LOOP
+        INSERT INTO test1 (a) VALUES (r.x);
+        ROLLBACK;
+    END LOOP;
+END;
+$$;
+ERROR:  cannot abort transaction inside a cursor loop
+CONTEXT:  PL/pgSQL function inline_code_block line 7 at ROLLBACK
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- commit inside block with exception handler
+TRUNCATE test1;
+DO LANGUAGE plpgsql $$
+BEGIN
+    BEGIN
+        INSERT INTO test1 (a) VALUES (1);
+        COMMIT;
+        INSERT INTO test1 (a) VALUES (1/0);
+        COMMIT;
+    EXCEPTION
+        WHEN division_by_zero THEN
+            RAISE NOTICE 'caught division_by_zero';
+    END;
+END;
+$$;
+ERROR:  cannot commit while a subtransaction is active
+CONTEXT:  PL/pgSQL function inline_code_block line 5 at COMMIT
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- rollback inside block with exception handler
+TRUNCATE test1;
+DO LANGUAGE plpgsql $$
+BEGIN
+    BEGIN
+        INSERT INTO test1 (a) VALUES (1);
+        ROLLBACK;
+        INSERT INTO test1 (a) VALUES (1/0);
+        ROLLBACK;
+    EXCEPTION
+        WHEN division_by_zero THEN
+            RAISE NOTICE 'caught division_by_zero';
+    END;
+END;
+$$;
+ERROR:  cannot roll back while a subtransaction is active
+CONTEXT:  PL/pgSQL function inline_code_block line 5 at ROLLBACK
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- COMMIT failures
+DO LANGUAGE plpgsql $$
+BEGIN
+    CREATE TABLE test3 (y int UNIQUE DEFERRABLE INITIALLY DEFERRED);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (1);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (1);
+    INSERT INTO test3 (y) VALUES (2);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (3);  -- won't get here
+END;
+$$;
+ERROR:  duplicate key value violates unique constraint "test3_y_key"
+DETAIL:  Key (y)=(1) already exists.
+CONTEXT:  PL/pgSQL function inline_code_block line 9 at COMMIT
+SELECT * FROM test3;
+ y 
+---
+ 1
+(1 row)
+
+DROP TABLE test1;
+DROP TABLE test2;
+DROP TABLE test3;
diff --git a/src/pl/plpgsql/src/pl_exec.c b/src/pl/plpgsql/src/pl_exec.c
index d096f242cd..4478c5332e 100644
--- a/src/pl/plpgsql/src/pl_exec.c
+++ b/src/pl/plpgsql/src/pl_exec.c
@@ -290,6 +290,10 @@ static int exec_stmt_dynexecute(PLpgSQL_execstate *estate,
 					 PLpgSQL_stmt_dynexecute *stmt);
 static int exec_stmt_dynfors(PLpgSQL_execstate *estate,
 				  PLpgSQL_stmt_dynfors *stmt);
+static int exec_stmt_commit(PLpgSQL_execstate *estate,
+				PLpgSQL_stmt_commit *stmt);
+static int exec_stmt_rollback(PLpgSQL_execstate *estate,
+				PLpgSQL_stmt_rollback *stmt);
 
 static void plpgsql_estate_setup(PLpgSQL_execstate *estate,
 					 PLpgSQL_function *func,
@@ -1731,6 +1735,14 @@ exec_stmt(PLpgSQL_execstate *estate, PLpgSQL_stmt *stmt)
 			rc = exec_stmt_close(estate, (PLpgSQL_stmt_close *) stmt);
 			break;
 
+		case PLPGSQL_STMT_COMMIT:
+			rc = exec_stmt_commit(estate, (PLpgSQL_stmt_commit *) stmt);
+			break;
+
+		case PLPGSQL_STMT_ROLLBACK:
+			rc = exec_stmt_rollback(estate, (PLpgSQL_stmt_rollback *) stmt);
+			break;
+
 		default:
 			estate->err_stmt = save_estmt;
 			elog(ERROR, "unrecognized cmdtype: %d", stmt->cmd_type);
@@ -4264,6 +4276,57 @@ exec_stmt_close(PLpgSQL_execstate *estate, PLpgSQL_stmt_close *stmt)
 	return PLPGSQL_RC_OK;
 }
 
+/*
+ * exec_stmt_commit
+ *
+ * Commit the transaction.
+ */
+static int
+exec_stmt_commit(PLpgSQL_execstate *estate, PLpgSQL_stmt_commit *stmt)
+{
+	/*
+	 * XXX This could be implemented by converting the pinned portals to
+	 * holdable ones and organizing the cleanup separately.
+	 */
+	if (ThereArePinnedPortals())
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("committing inside a cursor loop is not supported")));
+
+	SPI_commit();
+	SPI_start_transaction();
+
+	estate->simple_eval_estate = NULL;
+	plpgsql_create_econtext(estate);
+
+	return PLPGSQL_RC_OK;
+}
+
+/*
+ * exec_stmt_rollback
+ *
+ * Abort the transaction.
+ */
+static int
+exec_stmt_rollback(PLpgSQL_execstate *estate, PLpgSQL_stmt_rollback *stmt)
+{
+	/*
+	 * Unlike the COMMIT case above, this might not make sense at all,
+	 * especially if the query driving the cursor loop has side effects.
+	 */
+	if (ThereArePinnedPortals())
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("cannot abort transaction inside a cursor loop")));
+
+	SPI_rollback();
+	SPI_start_transaction();
+
+	estate->simple_eval_estate = NULL;
+	plpgsql_create_econtext(estate);
+
+	return PLPGSQL_RC_OK;
+}
 
 /* ----------
  * exec_assign_expr			Put an expression's result into a variable.
@@ -6767,8 +6830,7 @@ plpgsql_xact_cb(XactEvent event, void *arg)
 	 */
 	if (event == XACT_EVENT_COMMIT || event == XACT_EVENT_PREPARE)
 	{
-		/* Shouldn't be any econtext stack entries left at commit */
-		Assert(simple_econtext_stack == NULL);
+		simple_econtext_stack = NULL;
 
 		if (shared_simple_eval_estate)
 			FreeExecutorState(shared_simple_eval_estate);
diff --git a/src/pl/plpgsql/src/pl_funcs.c b/src/pl/plpgsql/src/pl_funcs.c
index 80b8448b7f..f0e85fcfcd 100644
--- a/src/pl/plpgsql/src/pl_funcs.c
+++ b/src/pl/plpgsql/src/pl_funcs.c
@@ -284,6 +284,10 @@ plpgsql_stmt_typename(PLpgSQL_stmt *stmt)
 			return "CLOSE";
 		case PLPGSQL_STMT_PERFORM:
 			return "PERFORM";
+		case PLPGSQL_STMT_COMMIT:
+			return "COMMIT";
+		case PLPGSQL_STMT_ROLLBACK:
+			return "ROLLBACK";
 	}
 
 	return "unknown";
@@ -363,6 +367,8 @@ static void free_open(PLpgSQL_stmt_open *stmt);
 static void free_fetch(PLpgSQL_stmt_fetch *stmt);
 static void free_close(PLpgSQL_stmt_close *stmt);
 static void free_perform(PLpgSQL_stmt_perform *stmt);
+static void free_commit(PLpgSQL_stmt_commit *stmt);
+static void free_rollback(PLpgSQL_stmt_rollback *stmt);
 static void free_expr(PLpgSQL_expr *expr);
 
 
@@ -443,6 +449,12 @@ free_stmt(PLpgSQL_stmt *stmt)
 		case PLPGSQL_STMT_PERFORM:
 			free_perform((PLpgSQL_stmt_perform *) stmt);
 			break;
+		case PLPGSQL_STMT_COMMIT:
+			free_commit((PLpgSQL_stmt_commit *) stmt);
+			break;
+		case PLPGSQL_STMT_ROLLBACK:
+			free_rollback((PLpgSQL_stmt_rollback *) stmt);
+			break;
 		default:
 			elog(ERROR, "unrecognized cmd_type: %d", stmt->cmd_type);
 			break;
@@ -590,6 +602,16 @@ free_perform(PLpgSQL_stmt_perform *stmt)
 	free_expr(stmt->expr);
 }
 
+static void
+free_commit(PLpgSQL_stmt_commit *stmt)
+{
+}
+
+static void
+free_rollback(PLpgSQL_stmt_rollback *stmt)
+{
+}
+
 static void
 free_exit(PLpgSQL_stmt_exit *stmt)
 {
@@ -777,6 +799,8 @@ static void dump_fetch(PLpgSQL_stmt_fetch *stmt);
 static void dump_cursor_direction(PLpgSQL_stmt_fetch *stmt);
 static void dump_close(PLpgSQL_stmt_close *stmt);
 static void dump_perform(PLpgSQL_stmt_perform *stmt);
+static void dump_commit(PLpgSQL_stmt_commit *stmt);
+static void dump_rollback(PLpgSQL_stmt_rollback *stmt);
 static void dump_expr(PLpgSQL_expr *expr);
 
 
@@ -867,6 +891,12 @@ dump_stmt(PLpgSQL_stmt *stmt)
 		case PLPGSQL_STMT_PERFORM:
 			dump_perform((PLpgSQL_stmt_perform *) stmt);
 			break;
+		case PLPGSQL_STMT_COMMIT:
+			dump_commit((PLpgSQL_stmt_commit *) stmt);
+			break;
+		case PLPGSQL_STMT_ROLLBACK:
+			dump_rollback((PLpgSQL_stmt_rollback *) stmt);
+			break;
 		default:
 			elog(ERROR, "unrecognized cmd_type: %d", stmt->cmd_type);
 			break;
@@ -1239,6 +1269,20 @@ dump_perform(PLpgSQL_stmt_perform *stmt)
 	printf("\n");
 }
 
+static void
+dump_commit(PLpgSQL_stmt_commit *stmt)
+{
+	dump_ind();
+	printf("COMMIT\n");
+}
+
+static void
+dump_rollback(PLpgSQL_stmt_rollback *stmt)
+{
+	dump_ind();
+	printf("ROLLBACK\n");
+}
+
 static void
 dump_exit(PLpgSQL_stmt_exit *stmt)
 {
diff --git a/src/pl/plpgsql/src/pl_gram.y b/src/pl/plpgsql/src/pl_gram.y
index d9cab1ad7e..42f6a2e161 100644
--- a/src/pl/plpgsql/src/pl_gram.y
+++ b/src/pl/plpgsql/src/pl_gram.y
@@ -198,6 +198,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %type <stmt>	stmt_return stmt_raise stmt_assert stmt_execsql
 %type <stmt>	stmt_dynexecute stmt_for stmt_perform stmt_getdiag
 %type <stmt>	stmt_open stmt_fetch stmt_move stmt_close stmt_null
+%type <stmt>	stmt_commit stmt_rollback
 %type <stmt>	stmt_case stmt_foreach_a
 
 %type <list>	proc_exceptions
@@ -260,6 +261,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %token <keyword>	K_COLLATE
 %token <keyword>	K_COLUMN
 %token <keyword>	K_COLUMN_NAME
+%token <keyword>	K_COMMIT
 %token <keyword>	K_CONSTANT
 %token <keyword>	K_CONSTRAINT
 %token <keyword>	K_CONSTRAINT_NAME
@@ -325,6 +327,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %token <keyword>	K_RETURN
 %token <keyword>	K_RETURNED_SQLSTATE
 %token <keyword>	K_REVERSE
+%token <keyword>	K_ROLLBACK
 %token <keyword>	K_ROW_COUNT
 %token <keyword>	K_ROWTYPE
 %token <keyword>	K_SCHEMA
@@ -897,6 +900,10 @@ proc_stmt		: pl_block ';'
 						{ $$ = $1; }
 				| stmt_null
 						{ $$ = $1; }
+				| stmt_commit
+						{ $$ = $1; }
+				| stmt_rollback
+						{ $$ = $1; }
 				;
 
 stmt_perform	: K_PERFORM expr_until_semi
@@ -2151,6 +2158,31 @@ stmt_null		: K_NULL ';'
 					}
 				;
 
+stmt_commit		: K_COMMIT ';'
+					{
+						PLpgSQL_stmt_commit *new;
+
+						new = palloc(sizeof(PLpgSQL_stmt_commit));
+						new->cmd_type = PLPGSQL_STMT_COMMIT;
+						new->lineno = plpgsql_location_to_lineno(@1);
+
+						$$ = (PLpgSQL_stmt *)new;
+					}
+				;
+
+stmt_rollback	: K_ROLLBACK ';'
+					{
+						PLpgSQL_stmt_rollback *new;
+
+						new = palloc(sizeof(PLpgSQL_stmt_rollback));
+						new->cmd_type = PLPGSQL_STMT_ROLLBACK;
+						new->lineno = plpgsql_location_to_lineno(@1);
+
+						$$ = (PLpgSQL_stmt *)new;
+					}
+				;
+
+
 cursor_variable	: T_DATUM
 					{
 						/*
@@ -2387,6 +2419,7 @@ unreserved_keyword	:
 				| K_COLLATE
 				| K_COLUMN
 				| K_COLUMN_NAME
+				| K_COMMIT
 				| K_CONSTANT
 				| K_CONSTRAINT
 				| K_CONSTRAINT_NAME
@@ -2438,6 +2471,7 @@ unreserved_keyword	:
 				| K_RETURN
 				| K_RETURNED_SQLSTATE
 				| K_REVERSE
+				| K_ROLLBACK
 				| K_ROW_COUNT
 				| K_ROWTYPE
 				| K_SCHEMA
diff --git a/src/pl/plpgsql/src/pl_handler.c b/src/pl/plpgsql/src/pl_handler.c
index 4c2ba2f734..a6868e552e 100644
--- a/src/pl/plpgsql/src/pl_handler.c
+++ b/src/pl/plpgsql/src/pl_handler.c
@@ -219,15 +219,20 @@ PG_FUNCTION_INFO_V1(plpgsql_call_handler);
 Datum
 plpgsql_call_handler(PG_FUNCTION_ARGS)
 {
+	bool		nonatomic;
 	PLpgSQL_function *func;
 	PLpgSQL_execstate *save_cur_estate;
 	Datum		retval;
 	int			rc;
 
+	nonatomic = fcinfo->context &&
+		IsA(fcinfo->context, CallContext) &&
+		!castNode(CallContext, fcinfo->context)->atomic;
+
 	/*
 	 * Connect to SPI manager
 	 */
-	if ((rc = SPI_connect()) != SPI_OK_CONNECT)
+	if ((rc = SPI_connect_ext(nonatomic ? SPI_OPT_NONATOMIC : 0)) != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed: %s", SPI_result_code_string(rc));
 
 	/* Find or compile the function */
@@ -255,7 +260,9 @@ plpgsql_call_handler(PG_FUNCTION_ARGS)
 			retval = (Datum) 0;
 		}
 		else
+		{
 			retval = plpgsql_exec_function(func, fcinfo, NULL);
+		}
 	}
 	PG_CATCH();
 	{
@@ -301,7 +308,7 @@ plpgsql_inline_handler(PG_FUNCTION_ARGS)
 	/*
 	 * Connect to SPI manager
 	 */
-	if ((rc = SPI_connect()) != SPI_OK_CONNECT)
+	if ((rc = SPI_connect_ext(codeblock->atomic ? 0 : SPI_OPT_NONATOMIC)) != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed: %s", SPI_result_code_string(rc));
 
 	/* Compile the anonymous code block */
diff --git a/src/pl/plpgsql/src/pl_scanner.c b/src/pl/plpgsql/src/pl_scanner.c
index ee9aef8bbc..12a3e6b818 100644
--- a/src/pl/plpgsql/src/pl_scanner.c
+++ b/src/pl/plpgsql/src/pl_scanner.c
@@ -106,6 +106,7 @@ static const ScanKeyword unreserved_keywords[] = {
 	PG_KEYWORD("collate", K_COLLATE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("column", K_COLUMN, UNRESERVED_KEYWORD)
 	PG_KEYWORD("column_name", K_COLUMN_NAME, UNRESERVED_KEYWORD)
+	PG_KEYWORD("commit", K_COMMIT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constant", K_CONSTANT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constraint", K_CONSTRAINT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constraint_name", K_CONSTRAINT_NAME, UNRESERVED_KEYWORD)
@@ -158,6 +159,7 @@ static const ScanKeyword unreserved_keywords[] = {
 	PG_KEYWORD("return", K_RETURN, UNRESERVED_KEYWORD)
 	PG_KEYWORD("returned_sqlstate", K_RETURNED_SQLSTATE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("reverse", K_REVERSE, UNRESERVED_KEYWORD)
+	PG_KEYWORD("rollback", K_ROLLBACK, UNRESERVED_KEYWORD)
 	PG_KEYWORD("row_count", K_ROW_COUNT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("rowtype", K_ROWTYPE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("schema", K_SCHEMA, UNRESERVED_KEYWORD)
diff --git a/src/pl/plpgsql/src/plpgsql.h b/src/pl/plpgsql/src/plpgsql.h
index c571afa34b..a9b9d91de7 100644
--- a/src/pl/plpgsql/src/plpgsql.h
+++ b/src/pl/plpgsql/src/plpgsql.h
@@ -105,7 +105,9 @@ typedef enum PLpgSQL_stmt_type
 	PLPGSQL_STMT_OPEN,
 	PLPGSQL_STMT_FETCH,
 	PLPGSQL_STMT_CLOSE,
-	PLPGSQL_STMT_PERFORM
+	PLPGSQL_STMT_PERFORM,
+	PLPGSQL_STMT_COMMIT,
+	PLPGSQL_STMT_ROLLBACK
 } PLpgSQL_stmt_type;
 
 /*
@@ -433,6 +435,24 @@ typedef struct PLpgSQL_stmt_perform
 	PLpgSQL_expr *expr;
 } PLpgSQL_stmt_perform;
 
+/*
+ * COMMIT statement
+ */
+typedef struct PLpgSQL_stmt_commit
+{
+	PLpgSQL_stmt_type cmd_type;
+	int			lineno;
+} PLpgSQL_stmt_commit;
+
+/*
+ * ROLLBACK statement
+ */
+typedef struct PLpgSQL_stmt_rollback
+{
+	PLpgSQL_stmt_type cmd_type;
+	int			lineno;
+} PLpgSQL_stmt_rollback;
+
 /*
  * GET DIAGNOSTICS item
  */
diff --git a/src/pl/plpgsql/src/sql/plpgsql_transaction.sql b/src/pl/plpgsql/src/sql/plpgsql_transaction.sql
new file mode 100644
index 0000000000..02ee735079
--- /dev/null
+++ b/src/pl/plpgsql/src/sql/plpgsql_transaction.sql
@@ -0,0 +1,215 @@
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+DO
+LANGUAGE plpgsql
+$$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+SELECT * FROM test1;
+
+
+-- transaction commands not allowed when called in transaction block
+START TRANSACTION;
+CALL transaction_test1();
+COMMIT;
+
+START TRANSACTION;
+DO LANGUAGE plpgsql $$ BEGIN COMMIT; END $$;
+COMMIT;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+    RETURN 1;
+END
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    CALL transaction_test1();
+    RETURN 1;
+END;
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    EXECUTE 'DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$';
+    RETURN 1;
+END;
+$$;
+
+SELECT transaction_test4();
+
+
+-- proconfig settings currently disallow transaction statements
+CREATE PROCEDURE transaction_test5()
+LANGUAGE plpgsql
+SET work_mem = 555
+AS $$
+BEGIN
+    COMMIT;
+END;
+$$;
+
+CALL transaction_test5();
+
+
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+
+TRUNCATE test1;
+
+DO LANGUAGE plpgsql $$
+DECLARE
+    r RECORD;
+BEGIN
+    FOR r IN SELECT * FROM test2 ORDER BY x LOOP
+        INSERT INTO test1 (a) VALUES (r.x);
+        COMMIT;
+    END LOOP;
+END;
+$$;
+
+SELECT * FROM test1;
+
+
+-- rollback inside cursor loop
+TRUNCATE test1;
+
+DO LANGUAGE plpgsql $$
+DECLARE
+    r RECORD;
+BEGIN
+    FOR r IN SELECT * FROM test2 ORDER BY x LOOP
+        INSERT INTO test1 (a) VALUES (r.x);
+        ROLLBACK;
+    END LOOP;
+END;
+$$;
+
+SELECT * FROM test1;
+
+
+-- commit inside block with exception handler
+TRUNCATE test1;
+
+DO LANGUAGE plpgsql $$
+BEGIN
+    BEGIN
+        INSERT INTO test1 (a) VALUES (1);
+        COMMIT;
+        INSERT INTO test1 (a) VALUES (1/0);
+        COMMIT;
+    EXCEPTION
+        WHEN division_by_zero THEN
+            RAISE NOTICE 'caught division_by_zero';
+    END;
+END;
+$$;
+
+SELECT * FROM test1;
+
+
+-- rollback inside block with exception handler
+TRUNCATE test1;
+
+DO LANGUAGE plpgsql $$
+BEGIN
+    BEGIN
+        INSERT INTO test1 (a) VALUES (1);
+        ROLLBACK;
+        INSERT INTO test1 (a) VALUES (1/0);
+        ROLLBACK;
+    EXCEPTION
+        WHEN division_by_zero THEN
+            RAISE NOTICE 'caught division_by_zero';
+    END;
+END;
+$$;
+
+SELECT * FROM test1;
+
+
+-- COMMIT failures
+DO LANGUAGE plpgsql $$
+BEGIN
+    CREATE TABLE test3 (y int UNIQUE DEFERRABLE INITIALLY DEFERRED);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (1);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (1);
+    INSERT INTO test3 (y) VALUES (2);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (3);  -- won't get here
+END;
+$$;
+
+SELECT * FROM test3;
+
+
+DROP TABLE test1;
+DROP TABLE test2;
+DROP TABLE test3;
diff --git a/src/pl/plpython/Makefile b/src/pl/plpython/Makefile
index cc91afebde..d09910835d 100644
--- a/src/pl/plpython/Makefile
+++ b/src/pl/plpython/Makefile
@@ -90,6 +90,7 @@ REGRESS = \
 	plpython_quote \
 	plpython_composite \
 	plpython_subtransaction \
+	plpython_transaction \
 	plpython_drop
 
 REGRESS_PLPYTHON3_MANGLE := $(REGRESS)
diff --git a/src/pl/plpython/expected/plpython_test.out b/src/pl/plpython/expected/plpython_test.out
index 847e4cc412..39b994f446 100644
--- a/src/pl/plpython/expected/plpython_test.out
+++ b/src/pl/plpython/expected/plpython_test.out
@@ -48,6 +48,7 @@ select module_contents();
  Error
  Fatal
  SPIError
+ commit
  cursor
  debug
  error
@@ -60,10 +61,11 @@ select module_contents();
  quote_ident
  quote_literal
  quote_nullable
+ rollback
  spiexceptions
  subtransaction
  warning
-(18 rows)
+(20 rows)
 
 CREATE FUNCTION elog_test_basic() RETURNS void
 AS $$
diff --git a/src/pl/plpython/expected/plpython_transaction.out b/src/pl/plpython/expected/plpython_transaction.out
new file mode 100644
index 0000000000..a94e136715
--- /dev/null
+++ b/src/pl/plpython/expected/plpython_transaction.out
@@ -0,0 +1,144 @@
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+DO
+LANGUAGE plpythonu
+$$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+return 1
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/Python function "transaction_test2"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("CALL transaction_test1()")
+return 1
+$$;
+SELECT transaction_test3();
+ERROR:  spiexceptions.InvalidTransactionTermination: invalid transaction termination
+CONTEXT:  Traceback (most recent call last):
+  PL/Python function "transaction_test3", line 2, in <module>
+    plpy.execute("CALL transaction_test1()")
+PL/Python function "transaction_test3"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$")
+return 1
+$$;
+SELECT transaction_test4();
+ERROR:  spiexceptions.InvalidTransactionTermination: invalid transaction termination
+CONTEXT:  Traceback (most recent call last):
+  PL/Python function "transaction_test4", line 2, in <module>
+    plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$")
+PL/Python function "transaction_test4"
+-- commit inside subtransaction (prohibited)
+DO LANGUAGE plpythonu $$
+with plpy.subtransaction():
+    plpy.commit()
+$$;
+WARNING:  forcibly aborting a subtransaction that has not been exited
+ERROR:  cannot commit while a subtransaction is active
+CONTEXT:  PL/Python anonymous code block
+-- FIXME
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+TRUNCATE test1;
+DO LANGUAGE plpythonu $$
+for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%s)" % row['x'])
+    plpy.commit()
+$$;
+ERROR:  ValueError: iterating a cursor in an aborted subtransaction
+CONTEXT:  Traceback (most recent call last):
+  PL/Python anonymous code block, line 2, in <module>
+    for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
+PL/Python anonymous code block
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+(1 row)
+
+-- FIXME
+-- rollback inside cursor loop
+TRUNCATE test1;
+DO LANGUAGE plpythonu $$
+for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%s)" % row['x'])
+    plpy.rollback()
+$$;
+ERROR:  ValueError: iterating a cursor in an aborted subtransaction
+CONTEXT:  Traceback (most recent call last):
+  PL/Python anonymous code block, line 2, in <module>
+    for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
+PL/Python anonymous code block
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+DROP TABLE test1;
+DROP TABLE test2;
diff --git a/src/pl/plpython/plpy_main.c b/src/pl/plpython/plpy_main.c
index 695de30583..527ba67fe1 100644
--- a/src/pl/plpython/plpy_main.c
+++ b/src/pl/plpython/plpy_main.c
@@ -219,14 +219,19 @@ plpython2_validator(PG_FUNCTION_ARGS)
 Datum
 plpython_call_handler(PG_FUNCTION_ARGS)
 {
+	bool		nonatomic;
 	Datum		retval;
 	PLyExecutionContext *exec_ctx;
 	ErrorContextCallback plerrcontext;
 
 	PLy_initialize();
 
+	nonatomic = fcinfo->context &&
+		IsA(fcinfo->context, CallContext) &&
+		!castNode(CallContext, fcinfo->context)->atomic;
+
 	/* Note: SPI_finish() happens in plpy_exec.c, which is dubious design */
-	if (SPI_connect() != SPI_OK_CONNECT)
+	if (SPI_connect_ext(nonatomic ? SPI_OPT_NONATOMIC : 0) != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed");
 
 	/*
@@ -303,7 +308,7 @@ plpython_inline_handler(PG_FUNCTION_ARGS)
 	PLy_initialize();
 
 	/* Note: SPI_finish() happens in plpy_exec.c, which is dubious design */
-	if (SPI_connect() != SPI_OK_CONNECT)
+	if (SPI_connect_ext(codeblock->atomic ? 0 : SPI_OPT_NONATOMIC) != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed");
 
 	MemSet(&fake_fcinfo, 0, sizeof(fake_fcinfo));
@@ -435,7 +440,7 @@ PLy_push_execution_context(void)
 	PLyExecutionContext *context;
 
 	context = (PLyExecutionContext *)
-		MemoryContextAlloc(TopTransactionContext, sizeof(PLyExecutionContext));
+		MemoryContextAlloc(PortalContext, sizeof(PLyExecutionContext));
 	context->curr_proc = NULL;
 	context->scratch_ctx = NULL;
 	context->next = PLy_execution_contexts;
diff --git a/src/pl/plpython/plpy_plpymodule.c b/src/pl/plpython/plpy_plpymodule.c
index 23f99e20ca..3d8983b3b3 100644
--- a/src/pl/plpython/plpy_plpymodule.c
+++ b/src/pl/plpython/plpy_plpymodule.c
@@ -6,8 +6,10 @@
 
 #include "postgres.h"
 
+#include "access/xact.h"
 #include "mb/pg_wchar.h"
 #include "utils/builtins.h"
+#include "utils/snapmgr.h"
 
 #include "plpython.h"
 
@@ -15,6 +17,7 @@
 
 #include "plpy_cursorobject.h"
 #include "plpy_elog.h"
+#include "plpy_main.h"
 #include "plpy_planobject.h"
 #include "plpy_resultobject.h"
 #include "plpy_spi.h"
@@ -41,6 +44,8 @@ static PyObject *PLy_fatal(PyObject *self, PyObject *args, PyObject *kw);
 static PyObject *PLy_quote_literal(PyObject *self, PyObject *args);
 static PyObject *PLy_quote_nullable(PyObject *self, PyObject *args);
 static PyObject *PLy_quote_ident(PyObject *self, PyObject *args);
+static PyObject *PLy_commit(PyObject *self, PyObject *args);
+static PyObject *PLy_rollback(PyObject *self, PyObject *args);
 
 
 /* A list of all known exceptions, generated from backend/utils/errcodes.txt */
@@ -95,6 +100,12 @@ static PyMethodDef PLy_methods[] = {
 	 */
 	{"cursor", PLy_cursor, METH_VARARGS, NULL},
 
+	/*
+	 * transaction control
+	 */
+	{"commit", PLy_commit, METH_NOARGS, NULL},
+	{"rollback", PLy_rollback, METH_NOARGS, NULL},
+
 	{NULL, NULL, 0, NULL}
 };
 
@@ -577,3 +588,31 @@ PLy_output(volatile int level, PyObject *self, PyObject *args, PyObject *kw)
 	 */
 	Py_RETURN_NONE;
 }
+
+static PyObject *
+PLy_commit(PyObject *self, PyObject *args)
+{
+	PLyExecutionContext *exec_ctx = PLy_current_execution_context();
+
+	SPI_commit();
+	SPI_start_transaction();
+
+	/* was cleared at transaction end, reset pointer */
+	exec_ctx->scratch_ctx = NULL;
+
+	Py_RETURN_NONE;
+}
+
+static PyObject *
+PLy_rollback(PyObject *self, PyObject *args)
+{
+	PLyExecutionContext *exec_ctx = PLy_current_execution_context();
+
+	SPI_rollback();
+	SPI_start_transaction();
+
+	/* was cleared at transaction end, reset pointer */
+	exec_ctx->scratch_ctx = NULL;
+
+	Py_RETURN_NONE;
+}
diff --git a/src/pl/plpython/sql/plpython_transaction.sql b/src/pl/plpython/sql/plpython_transaction.sql
new file mode 100644
index 0000000000..0cf74fed54
--- /dev/null
+++ b/src/pl/plpython/sql/plpython_transaction.sql
@@ -0,0 +1,117 @@
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+DO
+LANGUAGE plpythonu
+$$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+return 1
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("CALL transaction_test1()")
+return 1
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$")
+return 1
+$$;
+
+SELECT transaction_test4();
+
+
+-- commit inside subtransaction (prohibited)
+DO LANGUAGE plpythonu $$
+with plpy.subtransaction():
+    plpy.commit()
+$$;
+
+
+-- FIXME
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+
+TRUNCATE test1;
+
+DO LANGUAGE plpythonu $$
+for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%s)" % row['x'])
+    plpy.commit()
+$$;
+
+SELECT * FROM test1;
+
+
+-- FIXME
+-- rollback inside cursor loop
+TRUNCATE test1;
+
+DO LANGUAGE plpythonu $$
+for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%s)" % row['x'])
+    plpy.rollback()
+$$;
+
+SELECT * FROM test1;
+
+
+DROP TABLE test1;
+DROP TABLE test2;
diff --git a/src/pl/tcl/Makefile b/src/pl/tcl/Makefile
index 6a92a9b6aa..ef61ee596e 100644
--- a/src/pl/tcl/Makefile
+++ b/src/pl/tcl/Makefile
@@ -28,7 +28,7 @@ DATA = pltcl.control pltcl--1.0.sql pltcl--unpackaged--1.0.sql \
        pltclu.control pltclu--1.0.sql pltclu--unpackaged--1.0.sql
 
 REGRESS_OPTS = --dbname=$(PL_TESTDB) --load-extension=pltcl
-REGRESS = pltcl_setup pltcl_queries pltcl_call pltcl_start_proc pltcl_subxact pltcl_unicode
+REGRESS = pltcl_setup pltcl_queries pltcl_call pltcl_start_proc pltcl_subxact pltcl_unicode pltcl_transaction
 
 # Tcl on win32 ships with import libraries only for Microsoft Visual C++,
 # which are not compatible with mingw gcc. Therefore we need to build a
diff --git a/src/pl/tcl/expected/pltcl_transaction.out b/src/pl/tcl/expected/pltcl_transaction.out
new file mode 100644
index 0000000000..007204b99a
--- /dev/null
+++ b/src/pl/tcl/expected/pltcl_transaction.out
@@ -0,0 +1,100 @@
+-- suppress CONTEXT so that function OIDs aren't in output
+\set VERBOSITY terse
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+return 1
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE pltcl
+AS $$
+spi_exec "CALL transaction_test1()"
+return 1
+$$;
+SELECT transaction_test3();
+ERROR:  invalid transaction termination
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+TRUNCATE test1;
+CREATE PROCEDURE transaction_test4a()
+LANGUAGE pltcl
+AS $$
+spi_exec -array row "SELECT * FROM test2 ORDER BY x" {
+    spi_exec "INSERT INTO test1 (a) VALUES ($row(x))"
+    commit
+}
+$$;
+CALL transaction_test4a();
+ERROR:  cannot commit while a subtransaction is active
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- rollback inside cursor loop
+TRUNCATE test1;
+CREATE PROCEDURE transaction_test4b()
+LANGUAGE pltcl
+AS $$
+spi_exec -array row "SELECT * FROM test2 ORDER BY x" {
+    spi_exec "INSERT INTO test1 (a) VALUES ($row(x))"
+    rollback
+}
+$$;
+CALL transaction_test4b();
+ERROR:  cannot roll back while a subtransaction is active
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+DROP TABLE test1;
+DROP TABLE test2;
diff --git a/src/pl/tcl/pltcl.c b/src/pl/tcl/pltcl.c
index 8069784151..ab059252d5 100644
--- a/src/pl/tcl/pltcl.c
+++ b/src/pl/tcl/pltcl.c
@@ -312,6 +312,10 @@ static int pltcl_SPI_lastoid(ClientData cdata, Tcl_Interp *interp,
 				  int objc, Tcl_Obj *const objv[]);
 static int pltcl_subtransaction(ClientData cdata, Tcl_Interp *interp,
 					 int objc, Tcl_Obj *const objv[]);
+static int pltcl_commit(ClientData cdata, Tcl_Interp *interp,
+					 int objc, Tcl_Obj *const objv[]);
+static int pltcl_rollback(ClientData cdata, Tcl_Interp *interp,
+					 int objc, Tcl_Obj *const objv[]);
 
 static void pltcl_subtrans_begin(MemoryContext oldcontext,
 					 ResourceOwner oldowner);
@@ -524,6 +528,10 @@ pltcl_init_interp(pltcl_interp_desc *interp_desc, Oid prolang, bool pltrusted)
 						 pltcl_SPI_lastoid, NULL, NULL);
 	Tcl_CreateObjCommand(interp, "subtransaction",
 						 pltcl_subtransaction, NULL, NULL);
+	Tcl_CreateObjCommand(interp, "commit",
+						 pltcl_commit, NULL, NULL);
+	Tcl_CreateObjCommand(interp, "rollback",
+						 pltcl_rollback, NULL, NULL);
 
 	/************************************************************
 	 * Call the appropriate start_proc, if there is one.
@@ -797,6 +805,7 @@ static Datum
 pltcl_func_handler(PG_FUNCTION_ARGS, pltcl_call_state *call_state,
 				   bool pltrusted)
 {
+	bool		nonatomic;
 	pltcl_proc_desc *prodesc;
 	Tcl_Interp *volatile interp;
 	Tcl_Obj    *tcl_cmd;
@@ -804,8 +813,12 @@ pltcl_func_handler(PG_FUNCTION_ARGS, pltcl_call_state *call_state,
 	int			tcl_rc;
 	Datum		retval;
 
+	nonatomic = fcinfo->context &&
+		IsA(fcinfo->context, CallContext) &&
+		!castNode(CallContext, fcinfo->context)->atomic;
+
 	/* Connect to SPI manager */
-	if (SPI_connect() != SPI_OK_CONNECT)
+	if (SPI_connect_ext(nonatomic ? SPI_OPT_NONATOMIC : 0) != SPI_OK_CONNECT)
 		elog(ERROR, "could not connect to SPI manager");
 
 	/* Find or compile the function */
@@ -2936,6 +2949,86 @@ pltcl_subtransaction(ClientData cdata, Tcl_Interp *interp,
 }
 
 
+/**********************************************************************
+ * pltcl_commit()
+ *
+ * Commit the transaction and start a new one.
+ **********************************************************************/
+static int
+pltcl_commit(ClientData cdata, Tcl_Interp *interp,
+			 int objc, Tcl_Obj *const objv[])
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	PG_TRY();
+	{
+		SPI_commit();
+		SPI_start_transaction();
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Pass the error data to Tcl */
+		pltcl_construct_errorCode(interp, edata);
+		UTF_BEGIN;
+		Tcl_SetObjResult(interp, Tcl_NewStringObj(UTF_E2U(edata->message), -1));
+		UTF_END;
+		FreeErrorData(edata);
+
+		return TCL_ERROR;
+	}
+	PG_END_TRY();
+
+	return TCL_OK;
+}
+
+
+/**********************************************************************
+ * pltcl_rollback()
+ *
+ * Abort the transaction and start a new one.
+ **********************************************************************/
+static int
+pltcl_rollback(ClientData cdata, Tcl_Interp *interp,
+			   int objc, Tcl_Obj *const objv[])
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	PG_TRY();
+	{
+		SPI_rollback();
+		SPI_start_transaction();
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Pass the error data to Tcl */
+		pltcl_construct_errorCode(interp, edata);
+		UTF_BEGIN;
+		Tcl_SetObjResult(interp, Tcl_NewStringObj(UTF_E2U(edata->message), -1));
+		UTF_END;
+		FreeErrorData(edata);
+
+		return TCL_ERROR;
+	}
+	PG_END_TRY();
+
+	return TCL_OK;
+}
+
+
 /**********************************************************************
  * pltcl_set_tuple_values() - Set variables for all attributes
  *				  of a given tuple
diff --git a/src/pl/tcl/sql/pltcl_transaction.sql b/src/pl/tcl/sql/pltcl_transaction.sql
new file mode 100644
index 0000000000..c752faf665
--- /dev/null
+++ b/src/pl/tcl/sql/pltcl_transaction.sql
@@ -0,0 +1,98 @@
+-- suppress CONTEXT so that function OIDs aren't in output
+\set VERBOSITY terse
+
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+return 1
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE pltcl
+AS $$
+spi_exec "CALL transaction_test1()"
+return 1
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+
+TRUNCATE test1;
+
+CREATE PROCEDURE transaction_test4a()
+LANGUAGE pltcl
+AS $$
+spi_exec -array row "SELECT * FROM test2 ORDER BY x" {
+    spi_exec "INSERT INTO test1 (a) VALUES ($row(x))"
+    commit
+}
+$$;
+
+CALL transaction_test4a();
+
+SELECT * FROM test1;
+
+
+-- rollback inside cursor loop
+TRUNCATE test1;
+
+CREATE PROCEDURE transaction_test4b()
+LANGUAGE pltcl
+AS $$
+spi_exec -array row "SELECT * FROM test2 ORDER BY x" {
+    spi_exec "INSERT INTO test1 (a) VALUES ($row(x))"
+    rollback
+}
+$$;
+
+CALL transaction_test4b();
+
+SELECT * FROM test1;
+
+
+DROP TABLE test1;
+DROP TABLE test2;

base-commit: 84a6f63e32dbefe3dc76cbe628fab6cbfc26141e
-- 
2.15.1

#36Andrew Dunstan
andrew.dunstan@2ndquadrant.com
In reply to: Peter Eisentraut (#35)
Re: [HACKERS] Transaction control in procedures

On 01/05/2018 04:30 PM, Peter Eisentraut wrote:

A merge conflict has arisen, so for simplicity, here is an updated patch.

On 12/20/17 10:08, Peter Eisentraut wrote:

Updated patch attached.

I have addressed the most recent review comments I believe.

The question about what happens to cursor loops in PL/Perl and PL/Python
would be addressed by the separate thread "portal pinning". The test
cases in this patch are currently marked by FIXMEs.

I have changed the SPI API a bit. I got rid of SPI_set_nonatomic() and
instead introduced SPI_connect_ext() that you can pass flags to. The
advantage of that is that in the normal case we can continue to use the
existing memory contexts, so nothing changes for existing uses, which
seems desirable. (This also appears to address some sporadic test
failures in PL/Perl.)

I have also cleaned up the changes in portalmem.c further, so the
changes are now even smaller.

The commit message in this patch contains more details about some of
these changes.

Generally looks good.

This confused me slightly:

    +    Transactions cannot be ended inside loops through query results
    or inside
    +    blocks with exception handlers.

I suggest: "A transaction cannot be ended inside a loop over query
results, nor inside a block with exception handlers."

The patch has bitrotted slightly in src/backend/commands/portalcmds.c

The plperl expected file needs updating. Also, why does spi_commit() in
a loop result in an error message but not spi_rollback()?

cheers

andrew

--
Andrew Dunstan https://www.2ndQuadrant.com
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#37Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: Andrew Dunstan (#36)
1 attachment(s)
Re: [HACKERS] Transaction control in procedures

On 1/15/18 12:57, Andrew Dunstan wrote:

This confused me slightly:

+    Transactions cannot be ended inside loops through query results
or inside
+    blocks with exception handlers.

I suggest: "A transaction cannot be ended inside a loop over query
results, nor inside a block with exception handlers."

fixed

The patch has bitrotted slightly in src/backend/commands/portalcmds.c

merged

The plperl expected file needs updating. Also, why does spi_commit() in
a loop result in an error message but not spi_rollback()?

This is all changed now after the patch for portal pinning in PL/Perl
and PL/Python has been committed. The attached patch behaves better.

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

Attachments:

v7-0001-Transaction-control-in-PL-procedures.patchtext/plain; charset=UTF-8; name=v7-0001-Transaction-control-in-PL-procedures.patch; x-mac-creator=0; x-mac-type=0Download
From 84f35266cc63de1d433d8a5e3549a0e28cb4c1fc Mon Sep 17 00:00:00 2001
From: Peter Eisentraut <peter_e@gmx.net>
Date: Tue, 16 Jan 2018 10:12:44 -0500
Subject: [PATCH v7] Transaction control in PL procedures

In each of the supplied procedural languages (PL/pgSQL, PL/Perl,
PL/Python, PL/Tcl), add language-specific commit and rollback
functions/commands to control transactions in procedures in that
language.  Add similar underlying functions to SPI.  Some additional
cleanup so that transaction commit or abort doesn't blow away data
structures still used by the procedure call.  Add execution context
tracking to CALL and DO statements so that transaction control commands
can only be issued in top-level procedure and block calls, not function
calls or other procedure or block calls.

- SPI

Add a new function SPI_connect_ext() that is like SPI_connect() but
allows passing option flags.  The only option flag right now is
SPI_OPT_NONATOMIC.  A nonatomic SPI connection can execute transaction
control commands, otherwise it's not allowed.  This is meant to be
passed down from CALL and DO statements which themselves know in which
context they are called.  A nonatomic SPI connection uses different
memory management.  A normal SPI connection allocates its memory in
TopTransactionContext.  For nonatomic connections we use PortalContext
instead.  As the comment in SPI_connect_ext() (previously SPI_connect())
indicates, one could potentially use PortalContext in all cases, but it
seems safest to leave the existing uses alone, because this stuff is
complicated enough already.

SPI also gets new functions SPI_start_transaction(), SPI_commit(), and
SPI_rollback(), which can be used by PLs to implement their transaction
control logic.

- portalmem.c

Some adjustments were made in the code that cleans up portals at
transaction abort.  The portal code could already handle a command
*committing* a transaction and continuing (e.g., VACUUM), but it was not
quite prepared for a command *aborting* a transaction and continuing.

In AtAbort_Portals(), remove the code that marks an active portal as
failed.  As the comment there already predicted, this doesn't work if
the running command wants to keep running after transaction abort.  And
it's actually not necessary, because pquery.c is careful to run all
portal code in a PG_TRY block and explicitly runs MarkPortalFailed() if
there is an exception.  So the code in AtAbort_Portals() is never used
anyway.

In AtAbort_Portals() and AtCleanup_Portals(), we need to be careful not
to clean up active portals too much.  This mirrors similar code in
PreCommit_Portals().

- PL/Perl

Gets new functions spi_commit() and spi_rollback()

- PL/pgSQL

Gets new commands COMMIT and ROLLBACK.

Update the PL/SQL porting example in the documentation to reflect that
transactions are now possible in procedures.

- PL/Python

Gets new functions plpy.commit and plpy.rollback.

- PL/Tcl

Gets new commands commit and rollback.
---
 doc/src/sgml/plperl.sgml                           |  49 +++++
 doc/src/sgml/plpgsql.sgml                          |  91 ++++----
 doc/src/sgml/plpython.sgml                         |  39 ++++
 doc/src/sgml/pltcl.sgml                            |  41 ++++
 doc/src/sgml/ref/call.sgml                         |   7 +
 doc/src/sgml/ref/create_procedure.sgml             |   7 +
 doc/src/sgml/ref/do.sgml                           |   7 +
 doc/src/sgml/spi.sgml                              | 177 +++++++++++++++
 src/backend/commands/functioncmds.c                |  45 +++-
 src/backend/executor/spi.c                         |  99 ++++++++-
 src/backend/tcop/utility.c                         |   6 +-
 src/backend/utils/mmgr/portalmem.c                 |  49 +++--
 src/include/commands/defrem.h                      |   4 +-
 src/include/executor/spi.h                         |   7 +
 src/include/executor/spi_priv.h                    |   4 +
 src/include/nodes/nodes.h                          |   3 +-
 src/include/nodes/parsenodes.h                     |   7 +
 src/include/utils/portal.h                         |   1 +
 src/pl/plperl/GNUmakefile                          |   2 +-
 src/pl/plperl/SPI.xs                               |  10 +
 src/pl/plperl/expected/plperl_transaction.out      | 133 ++++++++++++
 src/pl/plperl/plperl.c                             |  69 +++++-
 src/pl/plperl/plperl.h                             |   2 +
 src/pl/plperl/sql/plperl_transaction.sql           | 120 ++++++++++
 src/pl/plpgsql/src/Makefile                        |   2 +-
 .../plpgsql/src/expected/plpgsql_transaction.out   | 241 +++++++++++++++++++++
 src/pl/plpgsql/src/pl_exec.c                       |  66 +++++-
 src/pl/plpgsql/src/pl_funcs.c                      |  44 ++++
 src/pl/plpgsql/src/pl_gram.y                       |  34 +++
 src/pl/plpgsql/src/pl_handler.c                    |  11 +-
 src/pl/plpgsql/src/pl_scanner.c                    |   2 +
 src/pl/plpgsql/src/plpgsql.h                       |  22 +-
 src/pl/plpgsql/src/sql/plpgsql_transaction.sql     | 215 ++++++++++++++++++
 src/pl/plpython/Makefile                           |   1 +
 src/pl/plpython/expected/plpython_test.out         |   4 +-
 src/pl/plpython/expected/plpython_transaction.out  | 135 ++++++++++++
 src/pl/plpython/plpy_main.c                        |  11 +-
 src/pl/plpython/plpy_plpymodule.c                  |  49 +++++
 src/pl/plpython/sql/plpython_transaction.sql       | 115 ++++++++++
 src/pl/tcl/Makefile                                |   2 +-
 src/pl/tcl/expected/pltcl_transaction.out          | 100 +++++++++
 src/pl/tcl/pltcl.c                                 |  95 +++++++-
 src/pl/tcl/sql/pltcl_transaction.sql               |  98 +++++++++
 43 files changed, 2134 insertions(+), 92 deletions(-)
 create mode 100644 src/pl/plperl/expected/plperl_transaction.out
 create mode 100644 src/pl/plperl/sql/plperl_transaction.sql
 create mode 100644 src/pl/plpgsql/src/expected/plpgsql_transaction.out
 create mode 100644 src/pl/plpgsql/src/sql/plpgsql_transaction.sql
 create mode 100644 src/pl/plpython/expected/plpython_transaction.out
 create mode 100644 src/pl/plpython/sql/plpython_transaction.sql
 create mode 100644 src/pl/tcl/expected/pltcl_transaction.out
 create mode 100644 src/pl/tcl/sql/pltcl_transaction.sql

diff --git a/doc/src/sgml/plperl.sgml b/doc/src/sgml/plperl.sgml
index 100162dead..9acd41310f 100644
--- a/doc/src/sgml/plperl.sgml
+++ b/doc/src/sgml/plperl.sgml
@@ -661,6 +661,55 @@ <title>Database Access from PL/Perl</title>
     </para>
     </listitem>
     </varlistentry>
+
+    <varlistentry>
+     <term>
+      <literal><function>spi_commit()</function></literal>
+      <indexterm>
+       <primary>spi_commit</primary>
+       <secondary>in PL/Perl</secondary>
+     </indexterm>
+     </term>
+     <term>
+      <literal><function>spi_rollback()</function></literal>
+      <indexterm>
+       <primary>spi_rollback</primary>
+       <secondary>in PL/Perl</secondary>
+      </indexterm>
+     </term>
+     <listitem>
+      <para>
+       Commit or roll back the current transaction.  This can only be called
+       in a procedure or anonymous code block (<command>DO</command> command)
+       called from the top level.  (Note that it is not possible to run the
+       SQL commands <command>COMMIT</command> or <command>ROLLBACK</command>
+       via <function>spi_exec_query</function> or similar.  It has to be done
+       using these functions.)  After a transaction is ended, a new
+       transaction is automatically started, so there is no separate function
+       for that.
+      </para>
+
+      <para>
+       Here is an example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+CALL transaction_test1();
+</programlisting>
+      </para>
+     </listitem>
+    </varlistentry>
    </variablelist>
  </sect2>
 
diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml
index ddd054c6cc..90a3c00dfe 100644
--- a/doc/src/sgml/plpgsql.sgml
+++ b/doc/src/sgml/plpgsql.sgml
@@ -3449,6 +3449,48 @@ <title>Looping Through a Cursor's Result</title>
 
   </sect1>
 
+  <sect1 id="plpgsql-transactions">
+   <title>Transaction Management</title>
+
+   <para>
+    In procedures invoked by the <command>CALL</command> command from the top
+    level as well as in anonymous code blocks (<command>DO</command> command)
+    called from the top level, it is possible to end transactions using the
+    commands <command>COMMIT</command> and <command>ROLLBACK</command>.  A new
+    transaction is started automatically after a transaction is ended using
+    these commands, so there is no separate <command>START
+    TRANSACTION</command> command.  (Note that <command>BEGIN</command> and
+    <command>END</command> have different meanings in PL/pgSQL.)
+   </para>
+
+   <para>
+    Here is a simple example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+CALL transaction_test1();
+</programlisting>
+   </para>
+
+   <para>
+    A transaction cannot be ended inside a loop over a query result, nor
+    inside a block with exception handlers.
+   </para>
+  </sect1>
+
   <sect1 id="plpgsql-errors-and-messages">
    <title>Errors and Messages</title>
 
@@ -5432,14 +5474,13 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
 <programlisting>
 CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id IN INTEGER) IS
     a_running_job_count INTEGER;
-    PRAGMA AUTONOMOUS_TRANSACTION; -- <co id="co.plpgsql-porting-pragma"/>
 BEGIN
-    LOCK TABLE cs_jobs IN EXCLUSIVE MODE; -- <co id="co.plpgsql-porting-locktable"/>
+    LOCK TABLE cs_jobs IN EXCLUSIVE MODE;
 
     SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL;
 
     IF a_running_job_count &gt; 0 THEN
-        COMMIT; -- free lock <co id="co.plpgsql-porting-commit"/>
+        COMMIT; -- free lock
         raise_application_error(-20000,
                  'Unable to create a new job: a job is currently running.');
     END IF;
@@ -5459,45 +5500,11 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
 </programlisting>
    </para>
 
-   <para>
-    Procedures like this can easily be converted into <productname>PostgreSQL</productname>
-    functions returning <type>void</type>. This procedure in
-    particular is interesting because it can teach us some things:
-
-    <calloutlist>
-     <callout arearefs="co.plpgsql-porting-pragma">
-      <para>
-       There is no <literal>PRAGMA</literal> statement in <productname>PostgreSQL</productname>.
-      </para>
-     </callout>
-
-     <callout arearefs="co.plpgsql-porting-locktable">
-      <para>
-       If you do a <command>LOCK TABLE</command> in <application>PL/pgSQL</application>,
-       the lock will not be released until the calling transaction is
-       finished.
-      </para>
-     </callout>
-
-     <callout arearefs="co.plpgsql-porting-commit">
-      <para>
-       You cannot issue <command>COMMIT</command> in a
-       <application>PL/pgSQL</application> function.  The function is
-       running within some outer transaction and so <command>COMMIT</command>
-       would imply terminating the function's execution.  However, in
-       this particular case it is not necessary anyway, because the lock
-       obtained by the <command>LOCK TABLE</command> will be released when
-       we raise an error.
-      </para>
-     </callout>
-    </calloutlist>
-   </para>
-
    <para>
     This is how we could port this procedure to <application>PL/pgSQL</application>:
 
 <programlisting>
-CREATE OR REPLACE FUNCTION cs_create_job(v_job_id integer) RETURNS void AS $$
+CREATE OR REPLACE PROCEDURE cs_create_job(v_job_id integer) AS $$
 DECLARE
     a_running_job_count integer;
 BEGIN
@@ -5506,6 +5513,7 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
     SELECT count(*) INTO a_running_job_count FROM cs_jobs WHERE end_stamp IS NULL;
 
     IF a_running_job_count &gt; 0 THEN
+        COMMIT; -- free lock
         RAISE EXCEPTION 'Unable to create a new job: a job is currently running'; -- <co id="co.plpgsql-porting-raise"/>
     END IF;
 
@@ -5518,6 +5526,7 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
         WHEN unique_violation THEN -- <co id="co.plpgsql-porting-exception"/>
             -- don't worry if it already exists
     END;
+    COMMIT;
 END;
 $$ LANGUAGE plpgsql;
 </programlisting>
@@ -5541,12 +5550,6 @@ <title>Porting a Procedure from <application>PL/SQL</application> to <applicatio
       </para>
      </callout>
     </calloutlist>
-
-    The main functional difference between this procedure and the
-    Oracle equivalent is that the exclusive lock on the <literal>cs_jobs</literal>
-    table will be held until the calling transaction completes.  Also, if
-    the caller later aborts (for example due to an error), the effects of
-    this procedure will be rolled back.
    </para>
    </example>
   </sect2>
diff --git a/doc/src/sgml/plpython.sgml b/doc/src/sgml/plpython.sgml
index 0dbeee1fa2..8641038abe 100644
--- a/doc/src/sgml/plpython.sgml
+++ b/doc/src/sgml/plpython.sgml
@@ -1370,6 +1370,45 @@ <title>Older Python Versions</title>
   </sect2>
  </sect1>
 
+ <sect1 id="plpython-transactions">
+  <title>Transaction Management</title>
+
+  <para>
+   In a procedure called from the top level or an anonymous code block
+   (<command>DO</command> command) called from the top level it is possible to
+   control transactions.  To commit the current transaction, call
+   <literal>plpy.commit()</literal>.  To roll back the current transaction,
+   call <literal>plpy.rollback()</literal>.  (Note that it is not possible to
+   run the SQL commands <command>COMMIT</command> or
+   <command>ROLLBACK</command> via <function>plpy.execute</function> or
+   similar.  It has to be done using these functions.)  After a transaction is
+   ended, a new transaction is automatically started, so there is no separate
+   function for that.
+  </para>
+
+  <para>
+   Here is an example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+CALL transaction_test1();
+</programlisting>
+  </para>
+
+  <para>
+   Transactions cannot be ended when an explicit subtransaction is active.
+  </para>
+ </sect1>
+
  <sect1 id="plpython-util">
   <title>Utility Functions</title>
   <para>
diff --git a/doc/src/sgml/pltcl.sgml b/doc/src/sgml/pltcl.sgml
index 8018783b0a..a834ab8862 100644
--- a/doc/src/sgml/pltcl.sgml
+++ b/doc/src/sgml/pltcl.sgml
@@ -1002,6 +1002,47 @@ <title>Explicit Subtransactions in PL/Tcl</title>
     </para>
    </sect1>
 
+   <sect1 id="pltcl-transactions">
+    <title>Transaction Management</title>
+
+    <para>
+     In a procedure called from the top level or an anonymous code block
+     (<command>DO</command> command) called from the top level it is possible
+     to control transactions.  To commit the current transaction, call the
+     <literal>commit</literal> command.  To roll back the current transaction,
+     call the <literal>rollback</literal> command.  (Note that it is not
+     possible to run the SQL commands <command>COMMIT</command> or
+     <command>ROLLBACK</command> via <function>spi_exec</function> or similar.
+     It has to be done using these functions.)  After a transaction is ended,
+     a new transaction is automatically started, so there is no separate
+     command for that.
+    </para>
+
+    <para>
+     Here is an example:
+<programlisting>
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i &lt; 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+
+CALL transaction_test1();
+</programlisting>
+    </para>
+
+    <para>
+     Transactions cannot be ended when an explicit subtransaction is active.
+    </para>
+   </sect1>
+
    <sect1 id="pltcl-config">
     <title>PL/Tcl Configuration</title>
 
diff --git a/doc/src/sgml/ref/call.sgml b/doc/src/sgml/ref/call.sgml
index 2741d8d15e..03da4518ee 100644
--- a/doc/src/sgml/ref/call.sgml
+++ b/doc/src/sgml/ref/call.sgml
@@ -70,6 +70,13 @@ <title>Notes</title>
   <para>
    To call a function (not a procedure), use <command>SELECT</command> instead.
   </para>
+
+  <para>
+   If <command>CALL</command> is executed in a transaction block, then the
+   called procedure cannot execute transaction control statements.
+   Transaction control statements are only allowed if <command>CALL</command>
+   is executed in its own transaction.
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_procedure.sgml b/doc/src/sgml/ref/create_procedure.sgml
index d712043824..bbf8b03d04 100644
--- a/doc/src/sgml/ref/create_procedure.sgml
+++ b/doc/src/sgml/ref/create_procedure.sgml
@@ -228,6 +228,13 @@ <title>Parameters</title>
        procedure exit, unless the current transaction is rolled back.
       </para>
 
+      <para>
+       If a <literal>SET</literal> clause is attached to a procedure, then
+       that procedure cannot execute transaction control statements (for
+       example, <command>COMMIT</command> and <command>ROLLBACK</command>,
+       depending on the language).
+      </para>
+
       <para>
        See <xref linkend="sql-set"/> and
        <xref linkend="runtime-config"/>
diff --git a/doc/src/sgml/ref/do.sgml b/doc/src/sgml/ref/do.sgml
index 061218b135..b9a6f9a6fd 100644
--- a/doc/src/sgml/ref/do.sgml
+++ b/doc/src/sgml/ref/do.sgml
@@ -91,6 +91,13 @@ <title>Notes</title>
    This is the same privilege requirement as for creating a function
    in the language.
   </para>
+
+  <para>
+   If <command>DO</command> is executed in a transaction block, then the
+   procedure code cannot execute transaction control statements.  Transaction
+   control statements are only allowed if <command>DO</command> is executed in
+   its own transaction.
+  </para>
  </refsect1>
 
  <refsect1 id="sql-do-examples">
diff --git a/doc/src/sgml/spi.sgml b/doc/src/sgml/spi.sgml
index 350f0863e9..10448922b1 100644
--- a/doc/src/sgml/spi.sgml
+++ b/doc/src/sgml/spi.sgml
@@ -64,6 +64,7 @@ <title>Interface Functions</title>
 
  <refentry id="spi-spi-connect">
   <indexterm><primary>SPI_connect</primary></indexterm>
+  <indexterm><primary>SPI_connect_ext</primary></indexterm>
 
   <refmeta>
    <refentrytitle>SPI_connect</refentrytitle>
@@ -72,12 +73,17 @@ <title>Interface Functions</title>
 
   <refnamediv>
    <refname>SPI_connect</refname>
+   <refname>SPI_connect_ext</refname>
    <refpurpose>connect a procedure to the SPI manager</refpurpose>
  </refnamediv>
 
  <refsynopsisdiv>
 <synopsis>
 int SPI_connect(void)
+</synopsis>
+
+ <synopsis>
+int SPI_connect_ext(int <parameter>options</parameter>)
 </synopsis>
  </refsynopsisdiv>
 
@@ -90,6 +96,31 @@ <title>Description</title>
    function if you want to execute commands through SPI.  Some utility
    SPI functions can be called from unconnected procedures.
   </para>
+
+  <para>
+   <function>SPI_connect_ext</function> does the same but has an argument that
+   allows passing option flags.  Currently, the following option values are
+   available:
+   <variablelist>
+    <varlistentry>
+     <term><symbol>SPI_OPT_NONATOMIC</symbol></term>
+     <listitem>
+      <para>
+       Sets the SPI connection to be <firstterm>nonatomic</firstterm>, which
+       means that transaction control calls <function>SPI_commit</function>,
+       <function>SPI_rollback</function>, and
+       <function>SPI_start_transaction</function> are allowed.  Otherwise,
+       calling these functions will result in an immediate error.
+      </para>
+     </listitem>
+    </varlistentry>
+   </variablelist>
+  </para>
+
+  <para>
+   <literal>SPI_connect()</literal> is equivalent to
+   <literal>SPI_connect_ext(0)</literal>.
+  </para>
  </refsect1>
 
  <refsect1>
@@ -4325,6 +4356,152 @@ <title>Return Value</title>
 
  </sect1>
 
+ <sect1 id="spi-transaction">
+  <title>Transaction Management</title>
+
+  <para>
+   It is not possible to run transaction control commands such
+   as <command>COMMIT</command> and <command>ROLLBACK</command> through SPI
+   functions such as <function>SPI_execute</function>.  There are, however,
+   separate interface functions that allow transaction control through SPI.
+  </para>
+
+  <para>
+   It is not generally safe and sensible to start and end transactions in
+   arbitrary user-defined SQL-callable functions without taking into account
+   the context in which they are called.  For example, a transaction boundary
+   in the middle of a function that is part of a complex SQL expression that
+   is part of some SQL command will probably result in obscure internal errors
+   or crashes.  The interface functions presented here are primarily intended
+   to be used by procedural language implementations to support transaction
+   management in procedures that are invoked by the <command>CALL</command>
+   command, taking the context of the <command>CALL</command> invocation into
+   account.  SPI procedures implemented in C can implement the same logic, but
+   the details of that are beyond the scope of this documentation.
+  </para>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-commit">
+ <indexterm><primary>SPI_commit</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_commit</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_commit</refname>
+  <refpurpose>commit the current transaction</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+void SPI_commit(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_commit</function> commits the current transaction.  It is
+   approximately equivalent to running the SQL
+   command <command>COMMIT</command>.  After a transaction is committed, a new
+   transaction has to be started
+   using <function>SPI_start_transaction</function> before further database
+   actions can be executed.
+  </para>
+
+  <para>
+   This function can only be executed if the SPI connection has been set as
+   nonatomic in the call to <function>SPI_connect_ext</function>.
+  </para>
+ </refsect1>
+</refentry>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-rollback">
+ <indexterm><primary>SPI_rollback</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_rollback</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_rollback</refname>
+  <refpurpose>abort the current transaction</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+void SPI_rollback(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_rollback</function> rolls back the current transaction.  It
+   is approximately equivalent to running the SQL
+   command <command>ROLLBACK</command>.  After a transaction is rolled back, a
+   new transaction has to be started
+   using <function>SPI_start_transaction</function> before further database
+   actions can be executed.
+  </para>
+
+  <para>
+   This function can only be executed if the SPI connection has been set as
+   nonatomic in the call to <function>SPI_connect_ext</function>.
+  </para>
+ </refsect1>
+</refentry>
+
+<!-- *********************************************** -->
+
+<refentry id="spi-spi-start-transaction">
+ <indexterm><primary>SPI_start_transaction</primary></indexterm>
+
+ <refmeta>
+  <refentrytitle>SPI_start_transaction</refentrytitle>
+  <manvolnum>3</manvolnum>
+ </refmeta>
+
+ <refnamediv>
+  <refname>SPI_start_transaction</refname>
+  <refpurpose>start a new transaction</refpurpose>
+ </refnamediv>
+
+ <refsynopsisdiv>
+<synopsis>
+void SPI_start_transaction(void)
+</synopsis>
+ </refsynopsisdiv>
+
+ <refsect1>
+  <title>Description</title>
+
+  <para>
+   <function>SPI_start_transaction</function> starts a new transaction.  It
+   can only be called after <function>SPI_commit</function>
+   or <function>SPI_rollback</function>, as there is no transaction active at
+   that point.  Normally, when an SPI procedure is called, there is already a
+   transaction active, so attempting to start another one before closing out
+   the current one will result in an error.
+  </para>
+
+  <para>
+   This function can only be executed if the SPI connection has been set as
+   nonatomic in the call to <function>SPI_connect_ext</function>.
+  </para>
+ </refsect1>
+</refentry>
+
+ </sect1>
+
  <sect1 id="spi-visibility">
   <title>Visibility of Data Changes</title>
 
diff --git a/src/backend/commands/functioncmds.c b/src/backend/commands/functioncmds.c
index 12ab33f418..9a33d33dcb 100644
--- a/src/backend/commands/functioncmds.c
+++ b/src/backend/commands/functioncmds.c
@@ -65,6 +65,7 @@
 #include "utils/fmgroids.h"
 #include "utils/guc.h"
 #include "utils/lsyscache.h"
+#include "utils/memutils.h"
 #include "utils/rel.h"
 #include "utils/syscache.h"
 #include "utils/tqual.h"
@@ -2138,7 +2139,7 @@ IsThereFunctionInNamespace(const char *proname, int pronargs,
  *		Execute inline procedural-language code
  */
 void
-ExecuteDoStmt(DoStmt *stmt)
+ExecuteDoStmt(DoStmt *stmt, bool atomic)
 {
 	InlineCodeBlock *codeblock = makeNode(InlineCodeBlock);
 	ListCell   *arg;
@@ -2200,6 +2201,7 @@ ExecuteDoStmt(DoStmt *stmt)
 	codeblock->langOid = HeapTupleGetOid(languageTuple);
 	languageStruct = (Form_pg_language) GETSTRUCT(languageTuple);
 	codeblock->langIsTrusted = languageStruct->lanpltrusted;
+	codeblock->atomic = atomic;
 
 	if (languageStruct->lanpltrusted)
 	{
@@ -2236,9 +2238,28 @@ ExecuteDoStmt(DoStmt *stmt)
 
 /*
  * Execute CALL statement
+ *
+ * Inside a top-level CALL statement, transaction-terminating commands such as
+ * COMMIT or a PL-specific equivalent are allowed.  The terminology in the SQL
+ * standard is that CALL establishes a non-atomic execution context.  Most
+ * other commands establish an atomic execution context, in which transaction
+ * control actions are not allowed.  If there are nested executions of CALL,
+ * we want to track the execution context recursively, so that the nested
+ * CALLs can also do transaction control.  Note, however, that for example in
+ * CALL -> SELECT -> CALL, the second call cannot do transaction control,
+ * because the SELECT in between establishes an atomic execution context.
+ *
+ * So when ExecuteCallStmt() is called from the top level, we pass in atomic =
+ * false (recall that that means transactions = yes).  We then create a
+ * CallContext node with content atomic = false, which is passed in the
+ * fcinfo->context field to the procedure invocation.  The language
+ * implementation should then take appropriate measures to allow or prevent
+ * transaction commands based on that information, e.g., call
+ * SPI_set_nonatomic().  The language should also pass on the atomic flag to
+ * any recursive invocations to CALL.
  */
 void
-ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
+ExecuteCallStmt(ParseState *pstate, CallStmt *stmt, bool atomic)
 {
 	List	   *targs;
 	ListCell   *lc;
@@ -2249,6 +2270,8 @@ ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
 	AclResult   aclresult;
 	FmgrInfo	flinfo;
 	FunctionCallInfoData fcinfo;
+	CallContext *callcontext;
+	HeapTuple	tp;
 
 	targs = NIL;
 	foreach(lc, stmt->funccall->args)
@@ -2284,8 +2307,24 @@ ExecuteCallStmt(ParseState *pstate, CallStmt *stmt)
 							   FUNC_MAX_ARGS,
 							   FUNC_MAX_ARGS)));
 
+	callcontext = makeNode(CallContext);
+	callcontext->atomic = atomic;
+
+	/*
+	 * If proconfig is set we can't allow transaction commands because of the
+	 * way the GUC stacking works: The transaction boundary would have to pop
+	 * the proconfig setting off the stack.  That restriction could be lifted
+	 * by redesigning the GUC nesting mechanism a bit.
+	 */
+	tp = SearchSysCache1(PROCOID, ObjectIdGetDatum(fexpr->funcid));
+	if (!HeapTupleIsValid(tp))
+		elog(ERROR, "cache lookup failed for function %u", fexpr->funcid);
+	if (!heap_attisnull(tp, Anum_pg_proc_proconfig))
+		callcontext->atomic = true;
+	ReleaseSysCache(tp);
+
 	fmgr_info(fexpr->funcid, &flinfo);
-	InitFunctionCallInfoData(fcinfo, &flinfo, nargs, fexpr->inputcollid, NULL, NULL);
+	InitFunctionCallInfoData(fcinfo, &flinfo, nargs, fexpr->inputcollid, (Node *) callcontext, NULL);
 
 	i = 0;
 	foreach (lc, fexpr->args)
diff --git a/src/backend/executor/spi.c b/src/backend/executor/spi.c
index 995f67d266..8e6a074244 100644
--- a/src/backend/executor/spi.c
+++ b/src/backend/executor/spi.c
@@ -82,6 +82,12 @@ static bool _SPI_checktuples(void);
 
 int
 SPI_connect(void)
+{
+	return SPI_connect_ext(0);
+}
+
+int
+SPI_connect_ext(int options)
 {
 	int			newdepth;
 
@@ -92,7 +98,7 @@ SPI_connect(void)
 			elog(ERROR, "SPI stack corrupted");
 		newdepth = 16;
 		_SPI_stack = (_SPI_connection *)
-			MemoryContextAlloc(TopTransactionContext,
+			MemoryContextAlloc(TopMemoryContext,
 							   newdepth * sizeof(_SPI_connection));
 		_SPI_stack_depth = newdepth;
 	}
@@ -124,19 +130,25 @@ SPI_connect(void)
 	_SPI_current->execCxt = NULL;
 	_SPI_current->connectSubid = GetCurrentSubTransactionId();
 	_SPI_current->queryEnv = NULL;
+	_SPI_current->atomic = (options & SPI_OPT_NONATOMIC ? false : true);
+	_SPI_current->internal_xact = false;
 
 	/*
 	 * Create memory contexts for this procedure
 	 *
-	 * XXX it would be better to use PortalContext as the parent context, but
-	 * we may not be inside a portal (consider deferred-trigger execution).
-	 * Perhaps CurTransactionContext would do?	For now it doesn't matter
-	 * because we clean up explicitly in AtEOSubXact_SPI().
+	 * In atomic contexts (the normal case), we use TopTransactionContext,
+	 * otherwise PortalContext, so that it lives across transaction
+	 * boundaries.
+	 *
+	 * XXX It could be better to use PortalContext as the parent context in
+	 * all cases, but we may not be inside a portal (consider deferred-trigger
+	 * execution).  Perhaps CurTransactionContext could be an option?  For now
+	 * it doesn't matter because we clean up explicitly in AtEOSubXact_SPI().
 	 */
-	_SPI_current->procCxt = AllocSetContextCreate(TopTransactionContext,
+	_SPI_current->procCxt = AllocSetContextCreate(_SPI_current->atomic ? TopTransactionContext : PortalContext,
 												  "SPI Proc",
 												  ALLOCSET_DEFAULT_SIZES);
-	_SPI_current->execCxt = AllocSetContextCreate(TopTransactionContext,
+	_SPI_current->execCxt = AllocSetContextCreate(_SPI_current->atomic ? TopTransactionContext : _SPI_current->procCxt,
 												  "SPI Exec",
 												  ALLOCSET_DEFAULT_SIZES);
 	/* ... and switch to procedure's context */
@@ -181,12 +193,82 @@ SPI_finish(void)
 	return SPI_OK_FINISH;
 }
 
+void
+SPI_start_transaction(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	StartTransactionCommand();
+	MemoryContextSwitchTo(oldcontext);
+}
+
+void
+SPI_commit(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	if (_SPI_current->atomic)
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("invalid transaction termination")));
+
+	/*
+	 * This restriction is required by PLs implemented on top of SPI.  They
+	 * use subtransactions to establish exception blocks that are supposed to
+	 * be rolled back together if there is an error.  Terminating the
+	 * top-level transaction in such a block violates that idea.  A future PL
+	 * implementation might have different ideas about this, in which case
+	 * this restriction would have to be refined or the check possibly be
+	 * moved out of SPI into the PLs.
+	 */
+	if (IsSubTransaction())
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("cannot commit while a subtransaction is active")));
+
+	_SPI_current->internal_xact = true;
+
+	if (ActiveSnapshotSet())
+		PopActiveSnapshot();
+	CommitTransactionCommand();
+	MemoryContextSwitchTo(oldcontext);
+
+	_SPI_current->internal_xact = false;
+}
+
+void
+SPI_rollback(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	if (_SPI_current->atomic)
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("invalid transaction termination")));
+
+	/* see under SPI_commit() */
+	if (IsSubTransaction())
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("cannot roll back while a subtransaction is active")));
+
+	_SPI_current->internal_xact = true;
+
+	AbortCurrentTransaction();
+	MemoryContextSwitchTo(oldcontext);
+
+	_SPI_current->internal_xact = false;
+}
+
 /*
  * Clean up SPI state at transaction commit or abort.
  */
 void
 AtEOXact_SPI(bool isCommit)
 {
+	if (_SPI_current && _SPI_current->internal_xact)
+		return;
+
 	/*
 	 * Note that memory contexts belonging to SPI stack entries will be freed
 	 * automatically, so we can ignore them here.  We just need to restore our
@@ -224,6 +306,9 @@ AtEOSubXact_SPI(bool isCommit, SubTransactionId mySubid)
 		if (connection->connectSubid != mySubid)
 			break;				/* couldn't be any underneath it either */
 
+		if (connection->internal_xact)
+			break;
+
 		found = true;
 
 		/*
diff --git a/src/backend/tcop/utility.c b/src/backend/tcop/utility.c
index ec98a612ec..0b8cfd0da4 100644
--- a/src/backend/tcop/utility.c
+++ b/src/backend/tcop/utility.c
@@ -529,7 +529,8 @@ standard_ProcessUtility(PlannedStmt *pstmt,
 			break;
 
 		case T_DoStmt:
-			ExecuteDoStmt((DoStmt *) parsetree);
+			ExecuteDoStmt((DoStmt *) parsetree,
+						  (context != PROCESS_UTILITY_TOPLEVEL || IsTransactionBlock()));
 			break;
 
 		case T_CreateTableSpaceStmt:
@@ -658,7 +659,8 @@ standard_ProcessUtility(PlannedStmt *pstmt,
 			break;
 
 		case T_CallStmt:
-			ExecuteCallStmt(pstate, castNode(CallStmt, parsetree));
+			ExecuteCallStmt(pstate, castNode(CallStmt, parsetree),
+							(context != PROCESS_UTILITY_TOPLEVEL || IsTransactionBlock()));
 			break;
 
 		case T_ClusterStmt:
diff --git a/src/backend/utils/mmgr/portalmem.c b/src/backend/utils/mmgr/portalmem.c
index 84c68ac189..f3f0add1d6 100644
--- a/src/backend/utils/mmgr/portalmem.c
+++ b/src/backend/utils/mmgr/portalmem.c
@@ -742,11 +742,8 @@ PreCommit_Portals(bool isPrepare)
 /*
  * Abort processing for portals.
  *
- * At this point we reset "active" status and run the cleanup hook if
- * present, but we can't release the portal's memory until the cleanup call.
- *
- * The reason we need to reset active is so that we can replace the unnamed
- * portal, else we'll fail to execute ROLLBACK when it arrives.
+ * At this point we run the cleanup hook if present, but we can't release the
+ * portal's memory until the cleanup call.
  */
 void
 AtAbort_Portals(void)
@@ -760,17 +757,6 @@ AtAbort_Portals(void)
 	{
 		Portal		portal = hentry->portal;
 
-		/*
-		 * See similar code in AtSubAbort_Portals().  This would fire if code
-		 * orchestrating multiple top-level transactions within a portal, such
-		 * as VACUUM, caught errors and continued under the same portal with a
-		 * fresh transaction.  No part of core PostgreSQL functions that way.
-		 * XXX Such code would wish the portal to remain ACTIVE, as in
-		 * PreCommit_Portals().
-		 */
-		if (portal->status == PORTAL_ACTIVE)
-			MarkPortalFailed(portal);
-
 		/*
 		 * Do nothing else to cursors held over from a previous transaction.
 		 */
@@ -810,9 +796,10 @@ AtAbort_Portals(void)
 		 * Although we can't delete the portal data structure proper, we can
 		 * release any memory in subsidiary contexts, such as executor state.
 		 * The cleanup hook was the last thing that might have needed data
-		 * there.
+		 * there.  But leave active portals alone.
 		 */
-		MemoryContextDeleteChildren(portal->portalContext);
+		if (portal->status != PORTAL_ACTIVE)
+			MemoryContextDeleteChildren(portal->portalContext);
 	}
 }
 
@@ -832,6 +819,13 @@ AtCleanup_Portals(void)
 	{
 		Portal		portal = hentry->portal;
 
+		/*
+		 * Do not touch active portals --- this can only happen in the case of
+		 * a multi-transaction command.
+		 */
+		if (portal->status == PORTAL_ACTIVE)
+			continue;
+
 		/* Do nothing to cursors held over from a previous transaction */
 		if (portal->createSubid == InvalidSubTransactionId)
 		{
@@ -1161,3 +1155,22 @@ ThereAreNoReadyPortals(void)
 
 	return true;
 }
+
+bool
+ThereArePinnedPortals(void)
+{
+	HASH_SEQ_STATUS status;
+	PortalHashEnt *hentry;
+
+	hash_seq_init(&status, PortalHashTable);
+
+	while ((hentry = (PortalHashEnt *) hash_seq_search(&status)) != NULL)
+	{
+		Portal		portal = hentry->portal;
+
+		if (portal->portalPinned)
+			return true;
+	}
+
+	return false;
+}
diff --git a/src/include/commands/defrem.h b/src/include/commands/defrem.h
index 1f18cad963..e0021878fb 100644
--- a/src/include/commands/defrem.h
+++ b/src/include/commands/defrem.h
@@ -58,8 +58,8 @@ extern ObjectAddress CreateTransform(CreateTransformStmt *stmt);
 extern void DropTransformById(Oid transformOid);
 extern void IsThereFunctionInNamespace(const char *proname, int pronargs,
 						   oidvector *proargtypes, Oid nspOid);
-extern void ExecuteDoStmt(DoStmt *stmt);
-extern void ExecuteCallStmt(ParseState *pstate, CallStmt *stmt);
+extern void ExecuteDoStmt(DoStmt *stmt, bool atomic);
+extern void ExecuteCallStmt(ParseState *pstate, CallStmt *stmt, bool atomic);
 extern Oid	get_cast_oid(Oid sourcetypeid, Oid targettypeid, bool missing_ok);
 extern Oid	get_transform_oid(Oid type_id, Oid lang_id, bool missing_ok);
 extern void interpret_function_parameter_list(ParseState *pstate,
diff --git a/src/include/executor/spi.h b/src/include/executor/spi.h
index 43580c5158..e5bdaecc4e 100644
--- a/src/include/executor/spi.h
+++ b/src/include/executor/spi.h
@@ -65,6 +65,8 @@ typedef struct _SPI_plan *SPIPlanPtr;
 #define SPI_OK_REL_UNREGISTER	16
 #define SPI_OK_TD_REGISTER		17
 
+#define SPI_OPT_NONATOMIC		(1 << 0)
+
 /* These used to be functions, now just no-ops for backwards compatibility */
 #define SPI_push()	((void) 0)
 #define SPI_pop()	((void) 0)
@@ -78,6 +80,7 @@ extern PGDLLIMPORT SPITupleTable *SPI_tuptable;
 extern PGDLLIMPORT int SPI_result;
 
 extern int	SPI_connect(void);
+extern int	SPI_connect_ext(int options);
 extern int	SPI_finish(void);
 extern int	SPI_execute(const char *src, bool read_only, long tcount);
 extern int SPI_execute_plan(SPIPlanPtr plan, Datum *Values, const char *Nulls,
@@ -156,6 +159,10 @@ extern int	SPI_register_relation(EphemeralNamedRelation enr);
 extern int	SPI_unregister_relation(const char *name);
 extern int	SPI_register_trigger_data(TriggerData *tdata);
 
+extern void SPI_start_transaction(void);
+extern void SPI_commit(void);
+extern void SPI_rollback(void);
+
 extern void AtEOXact_SPI(bool isCommit);
 extern void AtEOSubXact_SPI(bool isCommit, SubTransactionId mySubid);
 
diff --git a/src/include/executor/spi_priv.h b/src/include/executor/spi_priv.h
index 64f8a450eb..263c8f1453 100644
--- a/src/include/executor/spi_priv.h
+++ b/src/include/executor/spi_priv.h
@@ -36,6 +36,10 @@ typedef struct
 	MemoryContext savedcxt;		/* context of SPI_connect's caller */
 	SubTransactionId connectSubid;	/* ID of connecting subtransaction */
 	QueryEnvironment *queryEnv; /* query environment setup for SPI level */
+
+	/* transaction management support */
+	bool		atomic;			/* atomic execution context, does not allow transactions */
+	bool		internal_xact;	/* SPI-managed transaction boundary, skip cleanup */
 } _SPI_connection;
 
 /*
diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h
index 2eb3d6d371..74b094a9c3 100644
--- a/src/include/nodes/nodes.h
+++ b/src/include/nodes/nodes.h
@@ -500,7 +500,8 @@ typedef enum NodeTag
 	T_FdwRoutine,				/* in foreign/fdwapi.h */
 	T_IndexAmRoutine,			/* in access/amapi.h */
 	T_TsmRoutine,				/* in access/tsmapi.h */
-	T_ForeignKeyCacheInfo		/* in utils/rel.h */
+	T_ForeignKeyCacheInfo,		/* in utils/rel.h */
+	T_CallContext				/* in nodes/parsenodes.h */
 } NodeTag;
 
 /*
diff --git a/src/include/nodes/parsenodes.h b/src/include/nodes/parsenodes.h
index b72178efd1..ccc2fda662 100644
--- a/src/include/nodes/parsenodes.h
+++ b/src/include/nodes/parsenodes.h
@@ -2803,6 +2803,7 @@ typedef struct InlineCodeBlock
 	char	   *source_text;	/* source text of anonymous code block */
 	Oid			langOid;		/* OID of selected language */
 	bool		langIsTrusted;	/* trusted property of the language */
+	bool		atomic;			/* atomic execution context */
 } InlineCodeBlock;
 
 /* ----------------------
@@ -2815,6 +2816,12 @@ typedef struct CallStmt
 	FuncCall   *funccall;
 } CallStmt;
 
+typedef struct CallContext
+{
+	NodeTag		type;
+	bool		atomic;
+} CallContext;
+
 /* ----------------------
  *		Alter Object Rename Statement
  * ----------------------
diff --git a/src/include/utils/portal.h b/src/include/utils/portal.h
index bc9d52e506..b903cb0fbe 100644
--- a/src/include/utils/portal.h
+++ b/src/include/utils/portal.h
@@ -231,5 +231,6 @@ extern PlannedStmt *PortalGetPrimaryStmt(Portal portal);
 extern void PortalCreateHoldStore(Portal portal);
 extern void PortalHashTableDeleteAll(void);
 extern bool ThereAreNoReadyPortals(void);
+extern bool ThereArePinnedPortals(void);
 
 #endif							/* PORTAL_H */
diff --git a/src/pl/plperl/GNUmakefile b/src/pl/plperl/GNUmakefile
index b829027d05..933abb47c4 100644
--- a/src/pl/plperl/GNUmakefile
+++ b/src/pl/plperl/GNUmakefile
@@ -55,7 +55,7 @@ endif # win32
 SHLIB_LINK = $(perl_embed_ldflags)
 
 REGRESS_OPTS = --dbname=$(PL_TESTDB) --load-extension=plperl  --load-extension=plperlu
-REGRESS = plperl plperl_lc plperl_trigger plperl_shared plperl_elog plperl_util plperl_init plperlu plperl_array plperl_call
+REGRESS = plperl plperl_lc plperl_trigger plperl_shared plperl_elog plperl_util plperl_init plperlu plperl_array plperl_call plperl_transaction
 # if Perl can support two interpreters in one backend,
 # test plperl-and-plperlu cases
 ifneq ($(PERL),)
diff --git a/src/pl/plperl/SPI.xs b/src/pl/plperl/SPI.xs
index d9e6f579d4..de5d812cbd 100644
--- a/src/pl/plperl/SPI.xs
+++ b/src/pl/plperl/SPI.xs
@@ -17,6 +17,7 @@
 #define PG_NEED_PERL_XSUB_H
 #include "plperl.h"
 #include "plperl_helpers.h"
+#include "executor/spi.h"
 
 
 MODULE = PostgreSQL::InServer::SPI PREFIX = spi_
@@ -152,6 +153,15 @@ spi_spi_cursor_close(sv)
 		plperl_spi_cursor_close(cursor);
 		pfree(cursor);
 
+void
+spi_spi_commit()
+	CODE:
+		plperl_spi_commit();
+
+void
+spi_spi_rollback()
+	CODE:
+		plperl_spi_rollback();
 
 BOOT:
     items = 0;  /* avoid 'unused variable' warning */
diff --git a/src/pl/plperl/expected/plperl_transaction.out b/src/pl/plperl/expected/plperl_transaction.out
new file mode 100644
index 0000000000..bd7b7f8660
--- /dev/null
+++ b/src/pl/plperl/expected/plperl_transaction.out
@@ -0,0 +1,133 @@
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+DO
+LANGUAGE plperl
+$$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+return 1;
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination at line 5.
+CONTEXT:  PL/Perl function "transaction_test2"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query("CALL transaction_test1()");
+return 1;
+$$;
+SELECT transaction_test3();
+ERROR:  invalid transaction termination at line 5. at line 2.
+CONTEXT:  PL/Perl function "transaction_test3"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query('DO LANGUAGE plperl $x$ spi_commit(); $x$');
+return 1;
+$$;
+SELECT transaction_test4();
+ERROR:  invalid transaction termination at line 1. at line 2.
+CONTEXT:  PL/Perl function "transaction_test4"
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+TRUNCATE test1;
+DO LANGUAGE plperl $$
+my $sth = spi_query("SELECT * FROM test2 ORDER BY x");
+my $row;
+while (defined($row = spi_fetchrow($sth))) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES (" . $row->{x} . ")");
+    spi_commit();
+}
+$$;
+ERROR:  cannot commit transaction while a cursor is open at line 6.
+CONTEXT:  PL/Perl anonymous code block
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- rollback inside cursor loop
+TRUNCATE test1;
+DO LANGUAGE plperl $$
+my $sth = spi_query("SELECT * FROM test2 ORDER BY x");
+my $row;
+while (defined($row = spi_fetchrow($sth))) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES (" . $row->{x} . ")");
+    spi_rollback();
+}
+$$;
+ERROR:  cannot abort transaction while a cursor is open at line 6.
+CONTEXT:  PL/Perl anonymous code block
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+DROP TABLE test1;
+DROP TABLE test2;
diff --git a/src/pl/plperl/plperl.c b/src/pl/plperl/plperl.c
index 10feef11cf..77c41b2821 100644
--- a/src/pl/plperl/plperl.c
+++ b/src/pl/plperl/plperl.c
@@ -1929,7 +1929,7 @@ plperl_inline_handler(PG_FUNCTION_ARGS)
 
 		current_call_data = &this_call_data;
 
-		if (SPI_connect() != SPI_OK_CONNECT)
+		if (SPI_connect_ext(codeblock->atomic ? 0 : SPI_OPT_NONATOMIC) != SPI_OK_CONNECT)
 			elog(ERROR, "could not connect to SPI manager");
 
 		select_perl_context(desc.lanpltrusted);
@@ -2396,13 +2396,18 @@ plperl_call_perl_event_trigger_func(plperl_proc_desc *desc,
 static Datum
 plperl_func_handler(PG_FUNCTION_ARGS)
 {
+	bool		nonatomic;
 	plperl_proc_desc *prodesc;
 	SV		   *perlret;
 	Datum		retval = 0;
 	ReturnSetInfo *rsi;
 	ErrorContextCallback pl_error_context;
 
-	if (SPI_connect() != SPI_OK_CONNECT)
+	nonatomic = fcinfo->context &&
+		IsA(fcinfo->context, CallContext) &&
+		!castNode(CallContext, fcinfo->context)->atomic;
+
+	if (SPI_connect_ext(nonatomic ? SPI_OPT_NONATOMIC : 0) != SPI_OK_CONNECT)
 		elog(ERROR, "could not connect to SPI manager");
 
 	prodesc = compile_plperl_function(fcinfo->flinfo->fn_oid, false, false);
@@ -3953,6 +3958,66 @@ plperl_spi_freeplan(char *query)
 	SPI_freeplan(plan);
 }
 
+void
+plperl_spi_commit(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	PG_TRY();
+	{
+		if (ThereArePinnedPortals())
+			ereport(ERROR,
+					(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+					 errmsg("cannot commit transaction while a cursor is open")));
+
+		SPI_commit();
+		SPI_start_transaction();
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Punt the error to Perl */
+		croak_cstr(edata->message);
+	}
+	PG_END_TRY();
+}
+
+void
+plperl_spi_rollback(void)
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	PG_TRY();
+	{
+		if (ThereArePinnedPortals())
+			ereport(ERROR,
+					(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+					 errmsg("cannot abort transaction while a cursor is open")));
+
+		SPI_rollback();
+		SPI_start_transaction();
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Punt the error to Perl */
+		croak_cstr(edata->message);
+	}
+	PG_END_TRY();
+}
+
 /*
  * Implementation of plperl's elog() function
  *
diff --git a/src/pl/plperl/plperl.h b/src/pl/plperl/plperl.h
index 78366aac04..6fe7803088 100644
--- a/src/pl/plperl/plperl.h
+++ b/src/pl/plperl/plperl.h
@@ -125,6 +125,8 @@ HV		   *plperl_spi_exec_prepared(char *, HV *, int, SV **);
 SV		   *plperl_spi_query_prepared(char *, int, SV **);
 void		plperl_spi_freeplan(char *);
 void		plperl_spi_cursor_close(char *);
+void		plperl_spi_commit(void);
+void		plperl_spi_rollback(void);
 char	   *plperl_sv_to_literal(SV *, char *);
 void		plperl_util_elog(int level, SV *msg);
 
diff --git a/src/pl/plperl/sql/plperl_transaction.sql b/src/pl/plperl/sql/plperl_transaction.sql
new file mode 100644
index 0000000000..5c14d4732e
--- /dev/null
+++ b/src/pl/plperl/sql/plperl_transaction.sql
@@ -0,0 +1,120 @@
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+DO
+LANGUAGE plperl
+$$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+$$;
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plperl
+AS $$
+foreach my $i (0..9) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES ($i)");
+    if ($i % 2 == 0) {
+        spi_commit();
+    } else {
+        spi_rollback();
+    }
+}
+return 1;
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query("CALL transaction_test1()");
+return 1;
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plperl
+AS $$
+spi_exec_query('DO LANGUAGE plperl $x$ spi_commit(); $x$');
+return 1;
+$$;
+
+SELECT transaction_test4();
+
+
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+
+TRUNCATE test1;
+
+DO LANGUAGE plperl $$
+my $sth = spi_query("SELECT * FROM test2 ORDER BY x");
+my $row;
+while (defined($row = spi_fetchrow($sth))) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES (" . $row->{x} . ")");
+    spi_commit();
+}
+$$;
+
+SELECT * FROM test1;
+
+
+-- rollback inside cursor loop
+TRUNCATE test1;
+
+DO LANGUAGE plperl $$
+my $sth = spi_query("SELECT * FROM test2 ORDER BY x");
+my $row;
+while (defined($row = spi_fetchrow($sth))) {
+    spi_exec_query("INSERT INTO test1 (a) VALUES (" . $row->{x} . ")");
+    spi_rollback();
+}
+$$;
+
+SELECT * FROM test1;
+
+
+DROP TABLE test1;
+DROP TABLE test2;
diff --git a/src/pl/plpgsql/src/Makefile b/src/pl/plpgsql/src/Makefile
index 14a4d83584..91e1ada7ad 100644
--- a/src/pl/plpgsql/src/Makefile
+++ b/src/pl/plpgsql/src/Makefile
@@ -26,7 +26,7 @@ DATA = plpgsql.control plpgsql--1.0.sql plpgsql--unpackaged--1.0.sql
 
 REGRESS_OPTS = --dbname=$(PL_TESTDB)
 
-REGRESS = plpgsql_call plpgsql_control
+REGRESS = plpgsql_call plpgsql_control plpgsql_transaction
 
 all: all-lib
 
diff --git a/src/pl/plpgsql/src/expected/plpgsql_transaction.out b/src/pl/plpgsql/src/expected/plpgsql_transaction.out
new file mode 100644
index 0000000000..8ec22c646c
--- /dev/null
+++ b/src/pl/plpgsql/src/expected/plpgsql_transaction.out
@@ -0,0 +1,241 @@
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+DO
+LANGUAGE plpgsql
+$$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+-- transaction commands not allowed when called in transaction block
+START TRANSACTION;
+CALL transaction_test1();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function transaction_test1() line 6 at COMMIT
+COMMIT;
+START TRANSACTION;
+DO LANGUAGE plpgsql $$ BEGIN COMMIT; END $$;
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function inline_code_block line 1 at COMMIT
+COMMIT;
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+    RETURN 1;
+END
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function transaction_test2() line 6 at COMMIT
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    CALL transaction_test1();
+    RETURN 1;
+END;
+$$;
+SELECT transaction_test3();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function transaction_test1() line 6 at COMMIT
+SQL statement "CALL transaction_test1()"
+PL/pgSQL function transaction_test3() line 3 at SQL statement
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    EXECUTE 'DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$';
+    RETURN 1;
+END;
+$$;
+SELECT transaction_test4();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function inline_code_block line 1 at COMMIT
+SQL statement "DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$"
+PL/pgSQL function transaction_test4() line 3 at EXECUTE
+-- proconfig settings currently disallow transaction statements
+CREATE PROCEDURE transaction_test5()
+LANGUAGE plpgsql
+SET work_mem = 555
+AS $$
+BEGIN
+    COMMIT;
+END;
+$$;
+CALL transaction_test5();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/pgSQL function transaction_test5() line 3 at COMMIT
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+TRUNCATE test1;
+DO LANGUAGE plpgsql $$
+DECLARE
+    r RECORD;
+BEGIN
+    FOR r IN SELECT * FROM test2 ORDER BY x LOOP
+        INSERT INTO test1 (a) VALUES (r.x);
+        COMMIT;
+    END LOOP;
+END;
+$$;
+ERROR:  committing inside a cursor loop is not supported
+CONTEXT:  PL/pgSQL function inline_code_block line 7 at COMMIT
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- rollback inside cursor loop
+TRUNCATE test1;
+DO LANGUAGE plpgsql $$
+DECLARE
+    r RECORD;
+BEGIN
+    FOR r IN SELECT * FROM test2 ORDER BY x LOOP
+        INSERT INTO test1 (a) VALUES (r.x);
+        ROLLBACK;
+    END LOOP;
+END;
+$$;
+ERROR:  cannot abort transaction inside a cursor loop
+CONTEXT:  PL/pgSQL function inline_code_block line 7 at ROLLBACK
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- commit inside block with exception handler
+TRUNCATE test1;
+DO LANGUAGE plpgsql $$
+BEGIN
+    BEGIN
+        INSERT INTO test1 (a) VALUES (1);
+        COMMIT;
+        INSERT INTO test1 (a) VALUES (1/0);
+        COMMIT;
+    EXCEPTION
+        WHEN division_by_zero THEN
+            RAISE NOTICE 'caught division_by_zero';
+    END;
+END;
+$$;
+ERROR:  cannot commit while a subtransaction is active
+CONTEXT:  PL/pgSQL function inline_code_block line 5 at COMMIT
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- rollback inside block with exception handler
+TRUNCATE test1;
+DO LANGUAGE plpgsql $$
+BEGIN
+    BEGIN
+        INSERT INTO test1 (a) VALUES (1);
+        ROLLBACK;
+        INSERT INTO test1 (a) VALUES (1/0);
+        ROLLBACK;
+    EXCEPTION
+        WHEN division_by_zero THEN
+            RAISE NOTICE 'caught division_by_zero';
+    END;
+END;
+$$;
+ERROR:  cannot roll back while a subtransaction is active
+CONTEXT:  PL/pgSQL function inline_code_block line 5 at ROLLBACK
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- COMMIT failures
+DO LANGUAGE plpgsql $$
+BEGIN
+    CREATE TABLE test3 (y int UNIQUE DEFERRABLE INITIALLY DEFERRED);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (1);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (1);
+    INSERT INTO test3 (y) VALUES (2);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (3);  -- won't get here
+END;
+$$;
+ERROR:  duplicate key value violates unique constraint "test3_y_key"
+DETAIL:  Key (y)=(1) already exists.
+CONTEXT:  PL/pgSQL function inline_code_block line 9 at COMMIT
+SELECT * FROM test3;
+ y 
+---
+ 1
+(1 row)
+
+DROP TABLE test1;
+DROP TABLE test2;
+DROP TABLE test3;
diff --git a/src/pl/plpgsql/src/pl_exec.c b/src/pl/plpgsql/src/pl_exec.c
index d096f242cd..4478c5332e 100644
--- a/src/pl/plpgsql/src/pl_exec.c
+++ b/src/pl/plpgsql/src/pl_exec.c
@@ -290,6 +290,10 @@ static int exec_stmt_dynexecute(PLpgSQL_execstate *estate,
 					 PLpgSQL_stmt_dynexecute *stmt);
 static int exec_stmt_dynfors(PLpgSQL_execstate *estate,
 				  PLpgSQL_stmt_dynfors *stmt);
+static int exec_stmt_commit(PLpgSQL_execstate *estate,
+				PLpgSQL_stmt_commit *stmt);
+static int exec_stmt_rollback(PLpgSQL_execstate *estate,
+				PLpgSQL_stmt_rollback *stmt);
 
 static void plpgsql_estate_setup(PLpgSQL_execstate *estate,
 					 PLpgSQL_function *func,
@@ -1731,6 +1735,14 @@ exec_stmt(PLpgSQL_execstate *estate, PLpgSQL_stmt *stmt)
 			rc = exec_stmt_close(estate, (PLpgSQL_stmt_close *) stmt);
 			break;
 
+		case PLPGSQL_STMT_COMMIT:
+			rc = exec_stmt_commit(estate, (PLpgSQL_stmt_commit *) stmt);
+			break;
+
+		case PLPGSQL_STMT_ROLLBACK:
+			rc = exec_stmt_rollback(estate, (PLpgSQL_stmt_rollback *) stmt);
+			break;
+
 		default:
 			estate->err_stmt = save_estmt;
 			elog(ERROR, "unrecognized cmdtype: %d", stmt->cmd_type);
@@ -4264,6 +4276,57 @@ exec_stmt_close(PLpgSQL_execstate *estate, PLpgSQL_stmt_close *stmt)
 	return PLPGSQL_RC_OK;
 }
 
+/*
+ * exec_stmt_commit
+ *
+ * Commit the transaction.
+ */
+static int
+exec_stmt_commit(PLpgSQL_execstate *estate, PLpgSQL_stmt_commit *stmt)
+{
+	/*
+	 * XXX This could be implemented by converting the pinned portals to
+	 * holdable ones and organizing the cleanup separately.
+	 */
+	if (ThereArePinnedPortals())
+		ereport(ERROR,
+				(errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				 errmsg("committing inside a cursor loop is not supported")));
+
+	SPI_commit();
+	SPI_start_transaction();
+
+	estate->simple_eval_estate = NULL;
+	plpgsql_create_econtext(estate);
+
+	return PLPGSQL_RC_OK;
+}
+
+/*
+ * exec_stmt_rollback
+ *
+ * Abort the transaction.
+ */
+static int
+exec_stmt_rollback(PLpgSQL_execstate *estate, PLpgSQL_stmt_rollback *stmt)
+{
+	/*
+	 * Unlike the COMMIT case above, this might not make sense at all,
+	 * especially if the query driving the cursor loop has side effects.
+	 */
+	if (ThereArePinnedPortals())
+		ereport(ERROR,
+				(errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				 errmsg("cannot abort transaction inside a cursor loop")));
+
+	SPI_rollback();
+	SPI_start_transaction();
+
+	estate->simple_eval_estate = NULL;
+	plpgsql_create_econtext(estate);
+
+	return PLPGSQL_RC_OK;
+}
 
 /* ----------
  * exec_assign_expr			Put an expression's result into a variable.
@@ -6767,8 +6830,7 @@ plpgsql_xact_cb(XactEvent event, void *arg)
 	 */
 	if (event == XACT_EVENT_COMMIT || event == XACT_EVENT_PREPARE)
 	{
-		/* Shouldn't be any econtext stack entries left at commit */
-		Assert(simple_econtext_stack == NULL);
+		simple_econtext_stack = NULL;
 
 		if (shared_simple_eval_estate)
 			FreeExecutorState(shared_simple_eval_estate);
diff --git a/src/pl/plpgsql/src/pl_funcs.c b/src/pl/plpgsql/src/pl_funcs.c
index 80b8448b7f..f0e85fcfcd 100644
--- a/src/pl/plpgsql/src/pl_funcs.c
+++ b/src/pl/plpgsql/src/pl_funcs.c
@@ -284,6 +284,10 @@ plpgsql_stmt_typename(PLpgSQL_stmt *stmt)
 			return "CLOSE";
 		case PLPGSQL_STMT_PERFORM:
 			return "PERFORM";
+		case PLPGSQL_STMT_COMMIT:
+			return "COMMIT";
+		case PLPGSQL_STMT_ROLLBACK:
+			return "ROLLBACK";
 	}
 
 	return "unknown";
@@ -363,6 +367,8 @@ static void free_open(PLpgSQL_stmt_open *stmt);
 static void free_fetch(PLpgSQL_stmt_fetch *stmt);
 static void free_close(PLpgSQL_stmt_close *stmt);
 static void free_perform(PLpgSQL_stmt_perform *stmt);
+static void free_commit(PLpgSQL_stmt_commit *stmt);
+static void free_rollback(PLpgSQL_stmt_rollback *stmt);
 static void free_expr(PLpgSQL_expr *expr);
 
 
@@ -443,6 +449,12 @@ free_stmt(PLpgSQL_stmt *stmt)
 		case PLPGSQL_STMT_PERFORM:
 			free_perform((PLpgSQL_stmt_perform *) stmt);
 			break;
+		case PLPGSQL_STMT_COMMIT:
+			free_commit((PLpgSQL_stmt_commit *) stmt);
+			break;
+		case PLPGSQL_STMT_ROLLBACK:
+			free_rollback((PLpgSQL_stmt_rollback *) stmt);
+			break;
 		default:
 			elog(ERROR, "unrecognized cmd_type: %d", stmt->cmd_type);
 			break;
@@ -590,6 +602,16 @@ free_perform(PLpgSQL_stmt_perform *stmt)
 	free_expr(stmt->expr);
 }
 
+static void
+free_commit(PLpgSQL_stmt_commit *stmt)
+{
+}
+
+static void
+free_rollback(PLpgSQL_stmt_rollback *stmt)
+{
+}
+
 static void
 free_exit(PLpgSQL_stmt_exit *stmt)
 {
@@ -777,6 +799,8 @@ static void dump_fetch(PLpgSQL_stmt_fetch *stmt);
 static void dump_cursor_direction(PLpgSQL_stmt_fetch *stmt);
 static void dump_close(PLpgSQL_stmt_close *stmt);
 static void dump_perform(PLpgSQL_stmt_perform *stmt);
+static void dump_commit(PLpgSQL_stmt_commit *stmt);
+static void dump_rollback(PLpgSQL_stmt_rollback *stmt);
 static void dump_expr(PLpgSQL_expr *expr);
 
 
@@ -867,6 +891,12 @@ dump_stmt(PLpgSQL_stmt *stmt)
 		case PLPGSQL_STMT_PERFORM:
 			dump_perform((PLpgSQL_stmt_perform *) stmt);
 			break;
+		case PLPGSQL_STMT_COMMIT:
+			dump_commit((PLpgSQL_stmt_commit *) stmt);
+			break;
+		case PLPGSQL_STMT_ROLLBACK:
+			dump_rollback((PLpgSQL_stmt_rollback *) stmt);
+			break;
 		default:
 			elog(ERROR, "unrecognized cmd_type: %d", stmt->cmd_type);
 			break;
@@ -1239,6 +1269,20 @@ dump_perform(PLpgSQL_stmt_perform *stmt)
 	printf("\n");
 }
 
+static void
+dump_commit(PLpgSQL_stmt_commit *stmt)
+{
+	dump_ind();
+	printf("COMMIT\n");
+}
+
+static void
+dump_rollback(PLpgSQL_stmt_rollback *stmt)
+{
+	dump_ind();
+	printf("ROLLBACK\n");
+}
+
 static void
 dump_exit(PLpgSQL_stmt_exit *stmt)
 {
diff --git a/src/pl/plpgsql/src/pl_gram.y b/src/pl/plpgsql/src/pl_gram.y
index d9cab1ad7e..42f6a2e161 100644
--- a/src/pl/plpgsql/src/pl_gram.y
+++ b/src/pl/plpgsql/src/pl_gram.y
@@ -198,6 +198,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %type <stmt>	stmt_return stmt_raise stmt_assert stmt_execsql
 %type <stmt>	stmt_dynexecute stmt_for stmt_perform stmt_getdiag
 %type <stmt>	stmt_open stmt_fetch stmt_move stmt_close stmt_null
+%type <stmt>	stmt_commit stmt_rollback
 %type <stmt>	stmt_case stmt_foreach_a
 
 %type <list>	proc_exceptions
@@ -260,6 +261,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %token <keyword>	K_COLLATE
 %token <keyword>	K_COLUMN
 %token <keyword>	K_COLUMN_NAME
+%token <keyword>	K_COMMIT
 %token <keyword>	K_CONSTANT
 %token <keyword>	K_CONSTRAINT
 %token <keyword>	K_CONSTRAINT_NAME
@@ -325,6 +327,7 @@ static	void			check_raise_parameters(PLpgSQL_stmt_raise *stmt);
 %token <keyword>	K_RETURN
 %token <keyword>	K_RETURNED_SQLSTATE
 %token <keyword>	K_REVERSE
+%token <keyword>	K_ROLLBACK
 %token <keyword>	K_ROW_COUNT
 %token <keyword>	K_ROWTYPE
 %token <keyword>	K_SCHEMA
@@ -897,6 +900,10 @@ proc_stmt		: pl_block ';'
 						{ $$ = $1; }
 				| stmt_null
 						{ $$ = $1; }
+				| stmt_commit
+						{ $$ = $1; }
+				| stmt_rollback
+						{ $$ = $1; }
 				;
 
 stmt_perform	: K_PERFORM expr_until_semi
@@ -2151,6 +2158,31 @@ stmt_null		: K_NULL ';'
 					}
 				;
 
+stmt_commit		: K_COMMIT ';'
+					{
+						PLpgSQL_stmt_commit *new;
+
+						new = palloc(sizeof(PLpgSQL_stmt_commit));
+						new->cmd_type = PLPGSQL_STMT_COMMIT;
+						new->lineno = plpgsql_location_to_lineno(@1);
+
+						$$ = (PLpgSQL_stmt *)new;
+					}
+				;
+
+stmt_rollback	: K_ROLLBACK ';'
+					{
+						PLpgSQL_stmt_rollback *new;
+
+						new = palloc(sizeof(PLpgSQL_stmt_rollback));
+						new->cmd_type = PLPGSQL_STMT_ROLLBACK;
+						new->lineno = plpgsql_location_to_lineno(@1);
+
+						$$ = (PLpgSQL_stmt *)new;
+					}
+				;
+
+
 cursor_variable	: T_DATUM
 					{
 						/*
@@ -2387,6 +2419,7 @@ unreserved_keyword	:
 				| K_COLLATE
 				| K_COLUMN
 				| K_COLUMN_NAME
+				| K_COMMIT
 				| K_CONSTANT
 				| K_CONSTRAINT
 				| K_CONSTRAINT_NAME
@@ -2438,6 +2471,7 @@ unreserved_keyword	:
 				| K_RETURN
 				| K_RETURNED_SQLSTATE
 				| K_REVERSE
+				| K_ROLLBACK
 				| K_ROW_COUNT
 				| K_ROWTYPE
 				| K_SCHEMA
diff --git a/src/pl/plpgsql/src/pl_handler.c b/src/pl/plpgsql/src/pl_handler.c
index 4c2ba2f734..a6868e552e 100644
--- a/src/pl/plpgsql/src/pl_handler.c
+++ b/src/pl/plpgsql/src/pl_handler.c
@@ -219,15 +219,20 @@ PG_FUNCTION_INFO_V1(plpgsql_call_handler);
 Datum
 plpgsql_call_handler(PG_FUNCTION_ARGS)
 {
+	bool		nonatomic;
 	PLpgSQL_function *func;
 	PLpgSQL_execstate *save_cur_estate;
 	Datum		retval;
 	int			rc;
 
+	nonatomic = fcinfo->context &&
+		IsA(fcinfo->context, CallContext) &&
+		!castNode(CallContext, fcinfo->context)->atomic;
+
 	/*
 	 * Connect to SPI manager
 	 */
-	if ((rc = SPI_connect()) != SPI_OK_CONNECT)
+	if ((rc = SPI_connect_ext(nonatomic ? SPI_OPT_NONATOMIC : 0)) != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed: %s", SPI_result_code_string(rc));
 
 	/* Find or compile the function */
@@ -255,7 +260,9 @@ plpgsql_call_handler(PG_FUNCTION_ARGS)
 			retval = (Datum) 0;
 		}
 		else
+		{
 			retval = plpgsql_exec_function(func, fcinfo, NULL);
+		}
 	}
 	PG_CATCH();
 	{
@@ -301,7 +308,7 @@ plpgsql_inline_handler(PG_FUNCTION_ARGS)
 	/*
 	 * Connect to SPI manager
 	 */
-	if ((rc = SPI_connect()) != SPI_OK_CONNECT)
+	if ((rc = SPI_connect_ext(codeblock->atomic ? 0 : SPI_OPT_NONATOMIC)) != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed: %s", SPI_result_code_string(rc));
 
 	/* Compile the anonymous code block */
diff --git a/src/pl/plpgsql/src/pl_scanner.c b/src/pl/plpgsql/src/pl_scanner.c
index ee9aef8bbc..12a3e6b818 100644
--- a/src/pl/plpgsql/src/pl_scanner.c
+++ b/src/pl/plpgsql/src/pl_scanner.c
@@ -106,6 +106,7 @@ static const ScanKeyword unreserved_keywords[] = {
 	PG_KEYWORD("collate", K_COLLATE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("column", K_COLUMN, UNRESERVED_KEYWORD)
 	PG_KEYWORD("column_name", K_COLUMN_NAME, UNRESERVED_KEYWORD)
+	PG_KEYWORD("commit", K_COMMIT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constant", K_CONSTANT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constraint", K_CONSTRAINT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("constraint_name", K_CONSTRAINT_NAME, UNRESERVED_KEYWORD)
@@ -158,6 +159,7 @@ static const ScanKeyword unreserved_keywords[] = {
 	PG_KEYWORD("return", K_RETURN, UNRESERVED_KEYWORD)
 	PG_KEYWORD("returned_sqlstate", K_RETURNED_SQLSTATE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("reverse", K_REVERSE, UNRESERVED_KEYWORD)
+	PG_KEYWORD("rollback", K_ROLLBACK, UNRESERVED_KEYWORD)
 	PG_KEYWORD("row_count", K_ROW_COUNT, UNRESERVED_KEYWORD)
 	PG_KEYWORD("rowtype", K_ROWTYPE, UNRESERVED_KEYWORD)
 	PG_KEYWORD("schema", K_SCHEMA, UNRESERVED_KEYWORD)
diff --git a/src/pl/plpgsql/src/plpgsql.h b/src/pl/plpgsql/src/plpgsql.h
index c571afa34b..a9b9d91de7 100644
--- a/src/pl/plpgsql/src/plpgsql.h
+++ b/src/pl/plpgsql/src/plpgsql.h
@@ -105,7 +105,9 @@ typedef enum PLpgSQL_stmt_type
 	PLPGSQL_STMT_OPEN,
 	PLPGSQL_STMT_FETCH,
 	PLPGSQL_STMT_CLOSE,
-	PLPGSQL_STMT_PERFORM
+	PLPGSQL_STMT_PERFORM,
+	PLPGSQL_STMT_COMMIT,
+	PLPGSQL_STMT_ROLLBACK
 } PLpgSQL_stmt_type;
 
 /*
@@ -433,6 +435,24 @@ typedef struct PLpgSQL_stmt_perform
 	PLpgSQL_expr *expr;
 } PLpgSQL_stmt_perform;
 
+/*
+ * COMMIT statement
+ */
+typedef struct PLpgSQL_stmt_commit
+{
+	PLpgSQL_stmt_type cmd_type;
+	int			lineno;
+} PLpgSQL_stmt_commit;
+
+/*
+ * ROLLBACK statement
+ */
+typedef struct PLpgSQL_stmt_rollback
+{
+	PLpgSQL_stmt_type cmd_type;
+	int			lineno;
+} PLpgSQL_stmt_rollback;
+
 /*
  * GET DIAGNOSTICS item
  */
diff --git a/src/pl/plpgsql/src/sql/plpgsql_transaction.sql b/src/pl/plpgsql/src/sql/plpgsql_transaction.sql
new file mode 100644
index 0000000000..02ee735079
--- /dev/null
+++ b/src/pl/plpgsql/src/sql/plpgsql_transaction.sql
@@ -0,0 +1,215 @@
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+DO
+LANGUAGE plpgsql
+$$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+END
+$$;
+
+SELECT * FROM test1;
+
+
+-- transaction commands not allowed when called in transaction block
+START TRANSACTION;
+CALL transaction_test1();
+COMMIT;
+
+START TRANSACTION;
+DO LANGUAGE plpgsql $$ BEGIN COMMIT; END $$;
+COMMIT;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    FOR i IN 0..9 LOOP
+        INSERT INTO test1 (a) VALUES (i);
+        IF i % 2 = 0 THEN
+            COMMIT;
+        ELSE
+            ROLLBACK;
+        END IF;
+    END LOOP;
+    RETURN 1;
+END
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    CALL transaction_test1();
+    RETURN 1;
+END;
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plpgsql
+AS $$
+BEGIN
+    EXECUTE 'DO LANGUAGE plpgsql $x$ BEGIN COMMIT; END $x$';
+    RETURN 1;
+END;
+$$;
+
+SELECT transaction_test4();
+
+
+-- proconfig settings currently disallow transaction statements
+CREATE PROCEDURE transaction_test5()
+LANGUAGE plpgsql
+SET work_mem = 555
+AS $$
+BEGIN
+    COMMIT;
+END;
+$$;
+
+CALL transaction_test5();
+
+
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+
+TRUNCATE test1;
+
+DO LANGUAGE plpgsql $$
+DECLARE
+    r RECORD;
+BEGIN
+    FOR r IN SELECT * FROM test2 ORDER BY x LOOP
+        INSERT INTO test1 (a) VALUES (r.x);
+        COMMIT;
+    END LOOP;
+END;
+$$;
+
+SELECT * FROM test1;
+
+
+-- rollback inside cursor loop
+TRUNCATE test1;
+
+DO LANGUAGE plpgsql $$
+DECLARE
+    r RECORD;
+BEGIN
+    FOR r IN SELECT * FROM test2 ORDER BY x LOOP
+        INSERT INTO test1 (a) VALUES (r.x);
+        ROLLBACK;
+    END LOOP;
+END;
+$$;
+
+SELECT * FROM test1;
+
+
+-- commit inside block with exception handler
+TRUNCATE test1;
+
+DO LANGUAGE plpgsql $$
+BEGIN
+    BEGIN
+        INSERT INTO test1 (a) VALUES (1);
+        COMMIT;
+        INSERT INTO test1 (a) VALUES (1/0);
+        COMMIT;
+    EXCEPTION
+        WHEN division_by_zero THEN
+            RAISE NOTICE 'caught division_by_zero';
+    END;
+END;
+$$;
+
+SELECT * FROM test1;
+
+
+-- rollback inside block with exception handler
+TRUNCATE test1;
+
+DO LANGUAGE plpgsql $$
+BEGIN
+    BEGIN
+        INSERT INTO test1 (a) VALUES (1);
+        ROLLBACK;
+        INSERT INTO test1 (a) VALUES (1/0);
+        ROLLBACK;
+    EXCEPTION
+        WHEN division_by_zero THEN
+            RAISE NOTICE 'caught division_by_zero';
+    END;
+END;
+$$;
+
+SELECT * FROM test1;
+
+
+-- COMMIT failures
+DO LANGUAGE plpgsql $$
+BEGIN
+    CREATE TABLE test3 (y int UNIQUE DEFERRABLE INITIALLY DEFERRED);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (1);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (1);
+    INSERT INTO test3 (y) VALUES (2);
+    COMMIT;
+    INSERT INTO test3 (y) VALUES (3);  -- won't get here
+END;
+$$;
+
+SELECT * FROM test3;
+
+
+DROP TABLE test1;
+DROP TABLE test2;
+DROP TABLE test3;
diff --git a/src/pl/plpython/Makefile b/src/pl/plpython/Makefile
index cc91afebde..d09910835d 100644
--- a/src/pl/plpython/Makefile
+++ b/src/pl/plpython/Makefile
@@ -90,6 +90,7 @@ REGRESS = \
 	plpython_quote \
 	plpython_composite \
 	plpython_subtransaction \
+	plpython_transaction \
 	plpython_drop
 
 REGRESS_PLPYTHON3_MANGLE := $(REGRESS)
diff --git a/src/pl/plpython/expected/plpython_test.out b/src/pl/plpython/expected/plpython_test.out
index 847e4cc412..39b994f446 100644
--- a/src/pl/plpython/expected/plpython_test.out
+++ b/src/pl/plpython/expected/plpython_test.out
@@ -48,6 +48,7 @@ select module_contents();
  Error
  Fatal
  SPIError
+ commit
  cursor
  debug
  error
@@ -60,10 +61,11 @@ select module_contents();
  quote_ident
  quote_literal
  quote_nullable
+ rollback
  spiexceptions
  subtransaction
  warning
-(18 rows)
+(20 rows)
 
 CREATE FUNCTION elog_test_basic() RETURNS void
 AS $$
diff --git a/src/pl/plpython/expected/plpython_transaction.out b/src/pl/plpython/expected/plpython_transaction.out
new file mode 100644
index 0000000000..1fadc69b63
--- /dev/null
+++ b/src/pl/plpython/expected/plpython_transaction.out
@@ -0,0 +1,135 @@
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+DO
+LANGUAGE plpythonu
+$$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+return 1
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+CONTEXT:  PL/Python function "transaction_test2"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("CALL transaction_test1()")
+return 1
+$$;
+SELECT transaction_test3();
+ERROR:  spiexceptions.InvalidTransactionTermination: invalid transaction termination
+CONTEXT:  Traceback (most recent call last):
+  PL/Python function "transaction_test3", line 2, in <module>
+    plpy.execute("CALL transaction_test1()")
+PL/Python function "transaction_test3"
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$")
+return 1
+$$;
+SELECT transaction_test4();
+ERROR:  spiexceptions.InvalidTransactionTermination: invalid transaction termination
+CONTEXT:  Traceback (most recent call last):
+  PL/Python function "transaction_test4", line 2, in <module>
+    plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$")
+PL/Python function "transaction_test4"
+-- commit inside subtransaction (prohibited)
+DO LANGUAGE plpythonu $$
+with plpy.subtransaction():
+    plpy.commit()
+$$;
+WARNING:  forcibly aborting a subtransaction that has not been exited
+ERROR:  cannot commit while a subtransaction is active
+CONTEXT:  PL/Python anonymous code block
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+TRUNCATE test1;
+DO LANGUAGE plpythonu $$
+for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%s)" % row['x'])
+    plpy.commit()
+$$;
+ERROR:  cannot commit transaction while a cursor is open
+CONTEXT:  PL/Python anonymous code block
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- rollback inside cursor loop
+TRUNCATE test1;
+DO LANGUAGE plpythonu $$
+for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%s)" % row['x'])
+    plpy.rollback()
+$$;
+ERROR:  cannot abort transaction while a cursor is open
+CONTEXT:  PL/Python anonymous code block
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+DROP TABLE test1;
+DROP TABLE test2;
diff --git a/src/pl/plpython/plpy_main.c b/src/pl/plpython/plpy_main.c
index 695de30583..527ba67fe1 100644
--- a/src/pl/plpython/plpy_main.c
+++ b/src/pl/plpython/plpy_main.c
@@ -219,14 +219,19 @@ plpython2_validator(PG_FUNCTION_ARGS)
 Datum
 plpython_call_handler(PG_FUNCTION_ARGS)
 {
+	bool		nonatomic;
 	Datum		retval;
 	PLyExecutionContext *exec_ctx;
 	ErrorContextCallback plerrcontext;
 
 	PLy_initialize();
 
+	nonatomic = fcinfo->context &&
+		IsA(fcinfo->context, CallContext) &&
+		!castNode(CallContext, fcinfo->context)->atomic;
+
 	/* Note: SPI_finish() happens in plpy_exec.c, which is dubious design */
-	if (SPI_connect() != SPI_OK_CONNECT)
+	if (SPI_connect_ext(nonatomic ? SPI_OPT_NONATOMIC : 0) != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed");
 
 	/*
@@ -303,7 +308,7 @@ plpython_inline_handler(PG_FUNCTION_ARGS)
 	PLy_initialize();
 
 	/* Note: SPI_finish() happens in plpy_exec.c, which is dubious design */
-	if (SPI_connect() != SPI_OK_CONNECT)
+	if (SPI_connect_ext(codeblock->atomic ? 0 : SPI_OPT_NONATOMIC) != SPI_OK_CONNECT)
 		elog(ERROR, "SPI_connect failed");
 
 	MemSet(&fake_fcinfo, 0, sizeof(fake_fcinfo));
@@ -435,7 +440,7 @@ PLy_push_execution_context(void)
 	PLyExecutionContext *context;
 
 	context = (PLyExecutionContext *)
-		MemoryContextAlloc(TopTransactionContext, sizeof(PLyExecutionContext));
+		MemoryContextAlloc(PortalContext, sizeof(PLyExecutionContext));
 	context->curr_proc = NULL;
 	context->scratch_ctx = NULL;
 	context->next = PLy_execution_contexts;
diff --git a/src/pl/plpython/plpy_plpymodule.c b/src/pl/plpython/plpy_plpymodule.c
index 23f99e20ca..11d90e482d 100644
--- a/src/pl/plpython/plpy_plpymodule.c
+++ b/src/pl/plpython/plpy_plpymodule.c
@@ -6,8 +6,10 @@
 
 #include "postgres.h"
 
+#include "access/xact.h"
 #include "mb/pg_wchar.h"
 #include "utils/builtins.h"
+#include "utils/snapmgr.h"
 
 #include "plpython.h"
 
@@ -15,6 +17,7 @@
 
 #include "plpy_cursorobject.h"
 #include "plpy_elog.h"
+#include "plpy_main.h"
 #include "plpy_planobject.h"
 #include "plpy_resultobject.h"
 #include "plpy_spi.h"
@@ -41,6 +44,8 @@ static PyObject *PLy_fatal(PyObject *self, PyObject *args, PyObject *kw);
 static PyObject *PLy_quote_literal(PyObject *self, PyObject *args);
 static PyObject *PLy_quote_nullable(PyObject *self, PyObject *args);
 static PyObject *PLy_quote_ident(PyObject *self, PyObject *args);
+static PyObject *PLy_commit(PyObject *self, PyObject *args);
+static PyObject *PLy_rollback(PyObject *self, PyObject *args);
 
 
 /* A list of all known exceptions, generated from backend/utils/errcodes.txt */
@@ -95,6 +100,12 @@ static PyMethodDef PLy_methods[] = {
 	 */
 	{"cursor", PLy_cursor, METH_VARARGS, NULL},
 
+	/*
+	 * transaction control
+	 */
+	{"commit", PLy_commit, METH_NOARGS, NULL},
+	{"rollback", PLy_rollback, METH_NOARGS, NULL},
+
 	{NULL, NULL, 0, NULL}
 };
 
@@ -577,3 +588,41 @@ PLy_output(volatile int level, PyObject *self, PyObject *args, PyObject *kw)
 	 */
 	Py_RETURN_NONE;
 }
+
+static PyObject *
+PLy_commit(PyObject *self, PyObject *args)
+{
+	PLyExecutionContext *exec_ctx = PLy_current_execution_context();
+
+   if (ThereArePinnedPortals())
+	   ereport(ERROR,
+			   (errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
+				errmsg("cannot commit transaction while a cursor is open")));
+
+	SPI_commit();
+	SPI_start_transaction();
+
+	/* was cleared at transaction end, reset pointer */
+	exec_ctx->scratch_ctx = NULL;
+
+	Py_RETURN_NONE;
+}
+
+static PyObject *
+PLy_rollback(PyObject *self, PyObject *args)
+{
+	PLyExecutionContext *exec_ctx = PLy_current_execution_context();
+
+   if (ThereArePinnedPortals())
+	   ereport(ERROR,
+			   (errcode(ERRCODE_INVALID_TRANSACTION_TERMINATION),
+				errmsg("cannot abort transaction while a cursor is open")));
+
+	SPI_rollback();
+	SPI_start_transaction();
+
+	/* was cleared at transaction end, reset pointer */
+	exec_ctx->scratch_ctx = NULL;
+
+	Py_RETURN_NONE;
+}
diff --git a/src/pl/plpython/sql/plpython_transaction.sql b/src/pl/plpython/sql/plpython_transaction.sql
new file mode 100644
index 0000000000..36c7b2ef38
--- /dev/null
+++ b/src/pl/plpython/sql/plpython_transaction.sql
@@ -0,0 +1,115 @@
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+DO
+LANGUAGE plpythonu
+$$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+$$;
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE plpythonu
+AS $$
+for i in range(0, 10):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%d)" % i)
+    if i % 2 == 0:
+        plpy.commit()
+    else:
+        plpy.rollback()
+return 1
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("CALL transaction_test1()")
+return 1
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+-- DO block inside function
+CREATE FUNCTION transaction_test4() RETURNS int
+LANGUAGE plpythonu
+AS $$
+plpy.execute("DO LANGUAGE plpythonu $x$ plpy.commit() $x$")
+return 1
+$$;
+
+SELECT transaction_test4();
+
+
+-- commit inside subtransaction (prohibited)
+DO LANGUAGE plpythonu $$
+with plpy.subtransaction():
+    plpy.commit()
+$$;
+
+
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+
+TRUNCATE test1;
+
+DO LANGUAGE plpythonu $$
+for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%s)" % row['x'])
+    plpy.commit()
+$$;
+
+SELECT * FROM test1;
+
+
+-- rollback inside cursor loop
+TRUNCATE test1;
+
+DO LANGUAGE plpythonu $$
+for row in plpy.cursor("SELECT * FROM test2 ORDER BY x"):
+    plpy.execute("INSERT INTO test1 (a) VALUES (%s)" % row['x'])
+    plpy.rollback()
+$$;
+
+SELECT * FROM test1;
+
+
+DROP TABLE test1;
+DROP TABLE test2;
diff --git a/src/pl/tcl/Makefile b/src/pl/tcl/Makefile
index 6a92a9b6aa..ef61ee596e 100644
--- a/src/pl/tcl/Makefile
+++ b/src/pl/tcl/Makefile
@@ -28,7 +28,7 @@ DATA = pltcl.control pltcl--1.0.sql pltcl--unpackaged--1.0.sql \
        pltclu.control pltclu--1.0.sql pltclu--unpackaged--1.0.sql
 
 REGRESS_OPTS = --dbname=$(PL_TESTDB) --load-extension=pltcl
-REGRESS = pltcl_setup pltcl_queries pltcl_call pltcl_start_proc pltcl_subxact pltcl_unicode
+REGRESS = pltcl_setup pltcl_queries pltcl_call pltcl_start_proc pltcl_subxact pltcl_unicode pltcl_transaction
 
 # Tcl on win32 ships with import libraries only for Microsoft Visual C++,
 # which are not compatible with mingw gcc. Therefore we need to build a
diff --git a/src/pl/tcl/expected/pltcl_transaction.out b/src/pl/tcl/expected/pltcl_transaction.out
new file mode 100644
index 0000000000..007204b99a
--- /dev/null
+++ b/src/pl/tcl/expected/pltcl_transaction.out
@@ -0,0 +1,100 @@
+-- suppress CONTEXT so that function OIDs aren't in output
+\set VERBOSITY terse
+CREATE TABLE test1 (a int, b text);
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+CALL transaction_test1();
+SELECT * FROM test1;
+ a | b 
+---+---
+ 0 | 
+ 2 | 
+ 4 | 
+ 6 | 
+ 8 | 
+(5 rows)
+
+TRUNCATE test1;
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+return 1
+$$;
+SELECT transaction_test2();
+ERROR:  invalid transaction termination
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE pltcl
+AS $$
+spi_exec "CALL transaction_test1()"
+return 1
+$$;
+SELECT transaction_test3();
+ERROR:  invalid transaction termination
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+TRUNCATE test1;
+CREATE PROCEDURE transaction_test4a()
+LANGUAGE pltcl
+AS $$
+spi_exec -array row "SELECT * FROM test2 ORDER BY x" {
+    spi_exec "INSERT INTO test1 (a) VALUES ($row(x))"
+    commit
+}
+$$;
+CALL transaction_test4a();
+ERROR:  cannot commit while a subtransaction is active
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+-- rollback inside cursor loop
+TRUNCATE test1;
+CREATE PROCEDURE transaction_test4b()
+LANGUAGE pltcl
+AS $$
+spi_exec -array row "SELECT * FROM test2 ORDER BY x" {
+    spi_exec "INSERT INTO test1 (a) VALUES ($row(x))"
+    rollback
+}
+$$;
+CALL transaction_test4b();
+ERROR:  cannot roll back while a subtransaction is active
+SELECT * FROM test1;
+ a | b 
+---+---
+(0 rows)
+
+DROP TABLE test1;
+DROP TABLE test2;
diff --git a/src/pl/tcl/pltcl.c b/src/pl/tcl/pltcl.c
index 8069784151..ab059252d5 100644
--- a/src/pl/tcl/pltcl.c
+++ b/src/pl/tcl/pltcl.c
@@ -312,6 +312,10 @@ static int pltcl_SPI_lastoid(ClientData cdata, Tcl_Interp *interp,
 				  int objc, Tcl_Obj *const objv[]);
 static int pltcl_subtransaction(ClientData cdata, Tcl_Interp *interp,
 					 int objc, Tcl_Obj *const objv[]);
+static int pltcl_commit(ClientData cdata, Tcl_Interp *interp,
+					 int objc, Tcl_Obj *const objv[]);
+static int pltcl_rollback(ClientData cdata, Tcl_Interp *interp,
+					 int objc, Tcl_Obj *const objv[]);
 
 static void pltcl_subtrans_begin(MemoryContext oldcontext,
 					 ResourceOwner oldowner);
@@ -524,6 +528,10 @@ pltcl_init_interp(pltcl_interp_desc *interp_desc, Oid prolang, bool pltrusted)
 						 pltcl_SPI_lastoid, NULL, NULL);
 	Tcl_CreateObjCommand(interp, "subtransaction",
 						 pltcl_subtransaction, NULL, NULL);
+	Tcl_CreateObjCommand(interp, "commit",
+						 pltcl_commit, NULL, NULL);
+	Tcl_CreateObjCommand(interp, "rollback",
+						 pltcl_rollback, NULL, NULL);
 
 	/************************************************************
 	 * Call the appropriate start_proc, if there is one.
@@ -797,6 +805,7 @@ static Datum
 pltcl_func_handler(PG_FUNCTION_ARGS, pltcl_call_state *call_state,
 				   bool pltrusted)
 {
+	bool		nonatomic;
 	pltcl_proc_desc *prodesc;
 	Tcl_Interp *volatile interp;
 	Tcl_Obj    *tcl_cmd;
@@ -804,8 +813,12 @@ pltcl_func_handler(PG_FUNCTION_ARGS, pltcl_call_state *call_state,
 	int			tcl_rc;
 	Datum		retval;
 
+	nonatomic = fcinfo->context &&
+		IsA(fcinfo->context, CallContext) &&
+		!castNode(CallContext, fcinfo->context)->atomic;
+
 	/* Connect to SPI manager */
-	if (SPI_connect() != SPI_OK_CONNECT)
+	if (SPI_connect_ext(nonatomic ? SPI_OPT_NONATOMIC : 0) != SPI_OK_CONNECT)
 		elog(ERROR, "could not connect to SPI manager");
 
 	/* Find or compile the function */
@@ -2936,6 +2949,86 @@ pltcl_subtransaction(ClientData cdata, Tcl_Interp *interp,
 }
 
 
+/**********************************************************************
+ * pltcl_commit()
+ *
+ * Commit the transaction and start a new one.
+ **********************************************************************/
+static int
+pltcl_commit(ClientData cdata, Tcl_Interp *interp,
+			 int objc, Tcl_Obj *const objv[])
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	PG_TRY();
+	{
+		SPI_commit();
+		SPI_start_transaction();
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Pass the error data to Tcl */
+		pltcl_construct_errorCode(interp, edata);
+		UTF_BEGIN;
+		Tcl_SetObjResult(interp, Tcl_NewStringObj(UTF_E2U(edata->message), -1));
+		UTF_END;
+		FreeErrorData(edata);
+
+		return TCL_ERROR;
+	}
+	PG_END_TRY();
+
+	return TCL_OK;
+}
+
+
+/**********************************************************************
+ * pltcl_rollback()
+ *
+ * Abort the transaction and start a new one.
+ **********************************************************************/
+static int
+pltcl_rollback(ClientData cdata, Tcl_Interp *interp,
+			   int objc, Tcl_Obj *const objv[])
+{
+	MemoryContext oldcontext = CurrentMemoryContext;
+
+	PG_TRY();
+	{
+		SPI_rollback();
+		SPI_start_transaction();
+	}
+	PG_CATCH();
+	{
+		ErrorData  *edata;
+
+		/* Save error info */
+		MemoryContextSwitchTo(oldcontext);
+		edata = CopyErrorData();
+		FlushErrorState();
+
+		/* Pass the error data to Tcl */
+		pltcl_construct_errorCode(interp, edata);
+		UTF_BEGIN;
+		Tcl_SetObjResult(interp, Tcl_NewStringObj(UTF_E2U(edata->message), -1));
+		UTF_END;
+		FreeErrorData(edata);
+
+		return TCL_ERROR;
+	}
+	PG_END_TRY();
+
+	return TCL_OK;
+}
+
+
 /**********************************************************************
  * pltcl_set_tuple_values() - Set variables for all attributes
  *				  of a given tuple
diff --git a/src/pl/tcl/sql/pltcl_transaction.sql b/src/pl/tcl/sql/pltcl_transaction.sql
new file mode 100644
index 0000000000..c752faf665
--- /dev/null
+++ b/src/pl/tcl/sql/pltcl_transaction.sql
@@ -0,0 +1,98 @@
+-- suppress CONTEXT so that function OIDs aren't in output
+\set VERBOSITY terse
+
+CREATE TABLE test1 (a int, b text);
+
+
+CREATE PROCEDURE transaction_test1()
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+$$;
+
+CALL transaction_test1();
+
+SELECT * FROM test1;
+
+
+TRUNCATE test1;
+
+-- not allowed in a function
+CREATE FUNCTION transaction_test2() RETURNS int
+LANGUAGE pltcl
+AS $$
+for {set i 0} {$i < 10} {incr i} {
+    spi_exec "INSERT INTO test1 (a) VALUES ($i)"
+    if {$i % 2 == 0} {
+        commit
+    } else {
+        rollback
+    }
+}
+return 1
+$$;
+
+SELECT transaction_test2();
+
+SELECT * FROM test1;
+
+
+-- also not allowed if procedure is called from a function
+CREATE FUNCTION transaction_test3() RETURNS int
+LANGUAGE pltcl
+AS $$
+spi_exec "CALL transaction_test1()"
+return 1
+$$;
+
+SELECT transaction_test3();
+
+SELECT * FROM test1;
+
+
+-- commit inside cursor loop
+CREATE TABLE test2 (x int);
+INSERT INTO test2 VALUES (0), (1), (2), (3), (4);
+
+TRUNCATE test1;
+
+CREATE PROCEDURE transaction_test4a()
+LANGUAGE pltcl
+AS $$
+spi_exec -array row "SELECT * FROM test2 ORDER BY x" {
+    spi_exec "INSERT INTO test1 (a) VALUES ($row(x))"
+    commit
+}
+$$;
+
+CALL transaction_test4a();
+
+SELECT * FROM test1;
+
+
+-- rollback inside cursor loop
+TRUNCATE test1;
+
+CREATE PROCEDURE transaction_test4b()
+LANGUAGE pltcl
+AS $$
+spi_exec -array row "SELECT * FROM test2 ORDER BY x" {
+    spi_exec "INSERT INTO test1 (a) VALUES ($row(x))"
+    rollback
+}
+$$;
+
+CALL transaction_test4b();
+
+SELECT * FROM test1;
+
+
+DROP TABLE test1;
+DROP TABLE test2;

base-commit: 649aeb123f73e69cf78c52b534c15c51a229d63d
-- 
2.15.1

#38Andrew Dunstan
andrew.dunstan@2ndquadrant.com
In reply to: Peter Eisentraut (#37)
Re: [HACKERS] Transaction control in procedures

On 01/16/2018 10:16 AM, Peter Eisentraut wrote:

On 1/15/18 12:57, Andrew Dunstan wrote:

This confused me slightly:

+    Transactions cannot be ended inside loops through query results
or inside
+    blocks with exception handlers.

I suggest: "A transaction cannot be ended inside a loop over query
results, nor inside a block with exception handlers."

fixed

The patch has bitrotted slightly in src/backend/commands/portalcmds.c

merged

The plperl expected file needs updating. Also, why does spi_commit() in
a loop result in an error message but not spi_rollback()?

This is all changed now after the patch for portal pinning in PL/Perl
and PL/Python has been committed. The attached patch behaves better.

Looks good. Marking ready for committer.

cheers

andrew

--
Andrew Dunstan https://www.2ndQuadrant.com
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#39Simon Riggs
simon@2ndquadrant.com
In reply to: Merlin Moncure (#31)
Re: [HACKERS] Transaction control in procedures

On 6 December 2017 at 22:34, Merlin Moncure <mmoncure@gmail.com> wrote:

On Wed, Dec 6, 2017 at 8:41 AM, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

On 12/5/17 13:33, Robert Haas wrote:

On Tue, Dec 5, 2017 at 1:25 PM, Peter Eisentraut
<peter.eisentraut@2ndquadrant.com> wrote:

I think ROLLBACK in a cursor loop might not make sense, because the
cursor query itself could have side effects, so a rollback would have to
roll back the entire loop. That might need more refined analysis before
it could be allowed.

COMMIT really has the same problem; if the cursor query has side
effects, you can't commit those side effects piecemeal as the loop
executed and have things behave sanely.

The first COMMIT inside the loop would commit the cursor query. This
isn't all that different from what you'd get now if you coded this
manually using holdable cursors or just plain client code. Clearly, you
can create a mess if the loop body interacts with the loop expression,
but that's already the case.

But if you coded something like this yourself now and ran a ROLLBACK
inside the loop, the holdable cursor would disappear (unless previously
committed), so you couldn't proceed with the loop.

The SQL standard for persistent stored modules explicitly prohibits
COMMIT and ROLLBACK in cursor loop bodies. But I think people will
eventually want it.

The may want it, but silently promoting all cursors to held ones is
not the way to give it to them, unless we narrow it down the the
'for-loop derived cursor' only.

I don't think we should do that automatically for all cursors, but it
seems clear that we would want that iff the loop contains COMMIT or
ROLLBACK.

--
Simon Riggs http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#40Simon Riggs
simon@2ndquadrant.com
In reply to: Andrew Dunstan (#38)
Re: [HACKERS] Transaction control in procedures

On 16 January 2018 at 20:24, Andrew Dunstan
<andrew.dunstan@2ndquadrant.com> wrote:

Looks good. Marking ready for committer.

Few questions/points for the docs.

Docs say: "A new transaction is started automatically after a
transaction is ended using these commands"
Presumably this would have exactly the same isolation level and other
transaction characteristics?
(Is it somehow possible to vary that. OK if not, no problem)

The error "cannot commit while a subtransaction is active"
is commented as intending to prevent COMMIT/ROLLBACK inside an EXCEPTION block.
That makes sense. It seems it will also prevent SAVEPOINTs, though
that seems not to be intended.
The two cases are dissimilar and it would be possible to block the
former but allow the latter.

It's not documented or tested that SET LOCAL would work or not work.
Does it work?

--
Simon Riggs http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services

#41Peter Eisentraut
peter.eisentraut@2ndquadrant.com
In reply to: Andrew Dunstan (#38)
Re: [HACKERS] Transaction control in procedures

On 1/16/18 15:24, Andrew Dunstan wrote:

Looks good. Marking ready for committer.

committed

--
Peter Eisentraut http://www.2ndQuadrant.com/
PostgreSQL Development, 24x7 Support, Remote DBA, Training & Services