From 31b15fe8dcd2e026afc0b566f50141ae9a7273b5 Mon Sep 17 00:00:00 2001
From: Tom Lane <tgl@sss.pgh.pa.us>
Date: Tue, 4 Nov 2008 00:57:19 +0000
Subject: [PATCH] =?UTF-8?q?Disallow=20LOCK=20TABLE=20outside=20a=20transac?=
 =?UTF-8?q?tion=20block=20(or=20function),=20since=20this=20case=20almost?=
 =?UTF-8?q?=20certainly=20represents=20user=20error.=20=20Per=20a=20gripe?=
 =?UTF-8?q?=20from=20Sebastian=20B=C3=B6hm=20and=20subsequent=20discussion?=
 =?UTF-8?q?.?=
MIME-Version: 1.0
Content-Type: text/plain; charset=UTF-8
Content-Transfer-Encoding: 8bit

---
 doc/src/sgml/ref/declare.sgml            |  7 +++----
 doc/src/sgml/ref/lock.sgml               | 17 ++++++++++-------
 src/backend/tcop/utility.c               |  7 ++++++-
 src/test/regress/expected/privileges.out |  6 ++++++
 src/test/regress/sql/privileges.sql      |  6 ++++++
 5 files changed, 31 insertions(+), 12 deletions(-)

diff --git a/doc/src/sgml/ref/declare.sgml b/doc/src/sgml/ref/declare.sgml
index 269d2c101c4..744cda77726 100644
--- a/doc/src/sgml/ref/declare.sgml
+++ b/doc/src/sgml/ref/declare.sgml
@@ -1,5 +1,5 @@
 <!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/declare.sgml,v 1.42 2007/10/24 23:27:07 tgl Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/declare.sgml,v 1.43 2008/11/04 00:57:19 tgl Exp $
 PostgreSQL documentation
 -->
 
@@ -175,10 +175,9 @@ DECLARE <replaceable class="parameter">name</replaceable> [ BINARY ] [ INSENSITI
     <productname>PostgreSQL</productname> reports an error if such a
     command is used outside a transaction block.
     Use
-    <xref linkend="sql-begin" endterm="sql-begin-title">,
+    <xref linkend="sql-begin" endterm="sql-begin-title"> and
     <xref linkend="sql-commit" endterm="sql-commit-title">
-    and
-    <xref linkend="sql-rollback" endterm="sql-rollback-title">
+    (or <xref linkend="sql-rollback" endterm="sql-rollback-title">)
     to define a transaction block.
    </para>
 
diff --git a/doc/src/sgml/ref/lock.sgml b/doc/src/sgml/ref/lock.sgml
index d32e6d364c8..701c2a19a48 100644
--- a/doc/src/sgml/ref/lock.sgml
+++ b/doc/src/sgml/ref/lock.sgml
@@ -1,5 +1,5 @@
 <!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/lock.sgml,v 1.49 2008/09/08 00:47:40 tgl Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/lock.sgml,v 1.50 2008/11/04 00:57:19 tgl Exp $
 PostgreSQL documentation
 -->
 
@@ -160,12 +160,15 @@ where <replaceable class="PARAMETER">lockmode</replaceable> is one of:
    </para>
 
    <para>
-    <command>LOCK TABLE</command> is useful only inside a transaction
-    block (<command>BEGIN</>/<command>COMMIT</> pair), since the lock
-    is dropped as soon as the transaction ends.  A <command>LOCK
-    TABLE</> command appearing outside any transaction block forms a
-    self-contained transaction, so the lock will be dropped as soon as
-    it is obtained.
+    <command>LOCK TABLE</> is useless outside a transaction block: the lock
+    would remain held only to the completion of the statement.  Therefore
+    <productname>PostgreSQL</productname> reports an error if <command>LOCK</>
+    is used outside a transaction block.
+    Use
+    <xref linkend="sql-begin" endterm="sql-begin-title"> and
+    <xref linkend="sql-commit" endterm="sql-commit-title">
+    (or <xref linkend="sql-rollback" endterm="sql-rollback-title">)
+    to define a transaction block.
    </para>
 
   <para>
diff --git a/src/backend/tcop/utility.c b/src/backend/tcop/utility.c
index b1a0fe28ca5..1218e7cb9b8 100644
--- a/src/backend/tcop/utility.c
+++ b/src/backend/tcop/utility.c
@@ -10,7 +10,7 @@
  *
  *
  * IDENTIFICATION
- *	  $PostgreSQL: pgsql/src/backend/tcop/utility.c,v 1.299 2008/10/10 13:48:05 tgl Exp $
+ *	  $PostgreSQL: pgsql/src/backend/tcop/utility.c,v 1.300 2008/11/04 00:57:19 tgl Exp $
  *
  *-------------------------------------------------------------------------
  */
@@ -938,6 +938,11 @@ ProcessUtility(Node *parsetree,
 			break;
 
 		case T_LockStmt:
+			/*
+			 * Since the lock would just get dropped immediately, LOCK TABLE
+			 * outside a transaction block is presumed to be user error.
+			 */
+			RequireTransactionChain(isTopLevel, "LOCK TABLE");
 			LockTableCommand((LockStmt *) parsetree);
 			break;
 
diff --git a/src/test/regress/expected/privileges.out b/src/test/regress/expected/privileges.out
index 21f9fc26fd9..d1767e95ad4 100644
--- a/src/test/regress/expected/privileges.out
+++ b/src/test/regress/expected/privileges.out
@@ -45,7 +45,9 @@ INSERT INTO atest1 VALUES (1, 'one');
 DELETE FROM atest1;
 UPDATE atest1 SET a = 1 WHERE b = 'blech';
 TRUNCATE atest1;
+BEGIN;
 LOCK atest1 IN ACCESS EXCLUSIVE MODE;
+COMMIT;
 REVOKE ALL ON atest1 FROM PUBLIC;
 SELECT * FROM atest1;
  a | b 
@@ -102,8 +104,10 @@ DELETE FROM atest2; -- fail
 ERROR:  permission denied for relation atest2
 TRUNCATE atest2; -- fail
 ERROR:  permission denied for relation atest2
+BEGIN;
 LOCK atest2 IN ACCESS EXCLUSIVE MODE; -- fail
 ERROR:  permission denied for relation atest2
+COMMIT;
 COPY atest2 FROM stdin; -- fail
 ERROR:  permission denied for relation atest2
 GRANT ALL ON atest1 TO PUBLIC; -- fail
@@ -155,7 +159,9 @@ DELETE FROM atest2; -- fail
 ERROR:  permission denied for relation atest2
 TRUNCATE atest2; -- fail
 ERROR:  permission denied for relation atest2
+BEGIN;
 LOCK atest2 IN ACCESS EXCLUSIVE MODE; -- ok
+COMMIT;
 COPY atest2 FROM stdin; -- fail
 ERROR:  permission denied for relation atest2
 -- checks in subquery, both fail
diff --git a/src/test/regress/sql/privileges.sql b/src/test/regress/sql/privileges.sql
index 450d5d9d68d..63532f7e095 100644
--- a/src/test/regress/sql/privileges.sql
+++ b/src/test/regress/sql/privileges.sql
@@ -48,7 +48,9 @@ INSERT INTO atest1 VALUES (1, 'one');
 DELETE FROM atest1;
 UPDATE atest1 SET a = 1 WHERE b = 'blech';
 TRUNCATE atest1;
+BEGIN;
 LOCK atest1 IN ACCESS EXCLUSIVE MODE;
+COMMIT;
 
 REVOKE ALL ON atest1 FROM PUBLIC;
 SELECT * FROM atest1;
@@ -80,7 +82,9 @@ SELECT * FROM atest1 FOR UPDATE; -- ok
 SELECT * FROM atest2 FOR UPDATE; -- fail
 DELETE FROM atest2; -- fail
 TRUNCATE atest2; -- fail
+BEGIN;
 LOCK atest2 IN ACCESS EXCLUSIVE MODE; -- fail
+COMMIT;
 COPY atest2 FROM stdin; -- fail
 GRANT ALL ON atest1 TO PUBLIC; -- fail
 
@@ -105,7 +109,9 @@ SELECT * FROM atest1 FOR UPDATE; -- fail
 SELECT * FROM atest2 FOR UPDATE; -- fail
 DELETE FROM atest2; -- fail
 TRUNCATE atest2; -- fail
+BEGIN;
 LOCK atest2 IN ACCESS EXCLUSIVE MODE; -- ok
+COMMIT;
 COPY atest2 FROM stdin; -- fail
 
 -- checks in subquery, both fail
-- 
GitLab