From 93a6be63a55a8cd0d73b3fa81eb6a46013a3a974 Mon Sep 17 00:00:00 2001
From: Peter Eisentraut <peter_e@gmx.net>
Date: Tue, 20 Jan 2009 09:10:20 +0000
Subject: [PATCH] Revise the permission checking on user mapping DDL commands.
 CREATE/ALTER/DROP USER MAPPING are now allowed either by the server owner or
 by a user with USAGE privileges for his own user name.  This is more or less
 what the SQL standard wants anyway (plus "implementation-defined")

Hide information_schema.user_mapping_options.option_value, unless the current
user is the one associated with the user mapping, or is the server owner and
the mapping is for PUBLIC, or is a superuser.  This is to protect passwords.

Also, fix a bug in information_schema._pg_foreign_servers, which hid servers
using wrappers where the current user did not have privileges on the wrapper.
The correct behavior is to hide servers where the current user has no
privileges on the server.
---
 doc/src/sgml/information_schema.sgml       |  9 +++-
 doc/src/sgml/ref/alter_user_mapping.sgml   | 11 +++--
 doc/src/sgml/ref/create_user_mapping.sgml  | 11 +++--
 doc/src/sgml/ref/drop_user_mapping.sgml    | 12 +++--
 src/backend/catalog/information_schema.sql | 17 ++++---
 src/backend/commands/foreigncmds.c         | 56 ++++++++++++----------
 src/test/regress/expected/foreign_data.out | 15 ++++--
 src/test/regress/sql/foreign_data.sql      |  4 +-
 8 files changed, 89 insertions(+), 46 deletions(-)

diff --git a/doc/src/sgml/information_schema.sgml b/doc/src/sgml/information_schema.sgml
index f645c1252d6..96cbf1f12ad 100644
--- a/doc/src/sgml/information_schema.sgml
+++ b/doc/src/sgml/information_schema.sgml
@@ -1,4 +1,4 @@
-<!-- $PostgreSQL: pgsql/doc/src/sgml/information_schema.sgml,v 1.36 2008/12/19 16:25:16 petere Exp $ -->
+<!-- $PostgreSQL: pgsql/doc/src/sgml/information_schema.sgml,v 1.37 2009/01/20 09:10:20 petere Exp $ -->
 
 <chapter id="information-schema">
  <title>The Information Schema</title>
@@ -5081,7 +5081,12 @@ ORDER BY c.ordinal_position;
      <row>
       <entry><literal>option_value</literal></entry>
       <entry><type>character_data</type></entry>
-      <entry>Value of the option</entry>
+      <entry>Value of the option.  This column will show as null
+      unless the current user is the user being mapped, or the mapping
+      is for <literal>PUBLIC</literal> and the current user is the
+      server owner, or the current user is a superuser.  The intent is
+      to protect password information stored as user mapping
+      option.</entry>
      </row>
     </tbody>
    </tgroup>
diff --git a/doc/src/sgml/ref/alter_user_mapping.sgml b/doc/src/sgml/ref/alter_user_mapping.sgml
index 38bff39ece7..fef968a32e1 100644
--- a/doc/src/sgml/ref/alter_user_mapping.sgml
+++ b/doc/src/sgml/ref/alter_user_mapping.sgml
@@ -1,5 +1,5 @@
 <!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/alter_user_mapping.sgml,v 1.1 2008/12/19 16:25:16 petere Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/alter_user_mapping.sgml,v 1.2 2009/01/20 09:10:20 petere Exp $
 PostgreSQL documentation
 -->
 
@@ -31,10 +31,15 @@ ALTER USER MAPPING FOR { <replaceable class="parameter">username</replaceable> |
 
   <para>
    <command>ALTER USER MAPPING</command> changes the definition of a
-   user mapping.  Only the owner of the server can change the user
-   mappings of that server.
+   user mapping.
   </para>
 
+  <para>
+   The owner of a foreign server can alter user mappings for that
+   server for any user.  Also, a user can alter a user mapping for
+   his own user name if <literal>USAGE</> privilege on the server has
+   been granted to the user.
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/create_user_mapping.sgml b/doc/src/sgml/ref/create_user_mapping.sgml
index b0589817492..6857b3eb7e9 100644
--- a/doc/src/sgml/ref/create_user_mapping.sgml
+++ b/doc/src/sgml/ref/create_user_mapping.sgml
@@ -1,5 +1,5 @@
 <!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/create_user_mapping.sgml,v 1.2 2009/01/17 04:24:41 neilc Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/create_user_mapping.sgml,v 1.3 2009/01/20 09:10:20 petere Exp $
 PostgreSQL documentation
 -->
 
@@ -31,10 +31,15 @@ CREATE USER MAPPING FOR { <replaceable class="parameter">username</replaceable>
 
   <para>
    <command>CREATE USER MAPPING</command> defines a mapping of a user
-   to a foreign server.  You must be the owner of the server to define
-   user mappings for it.
+   to a foreign server.
   </para>
 
+  <para>
+   The owner of a foreign server can create user mappings for that
+   server for any user.  Also, a user can create a user mapping for
+   his own user name if <literal>USAGE</> privilege on the server has
+   been granted to the user.
+  </para>
  </refsect1>
 
  <refsect1>
diff --git a/doc/src/sgml/ref/drop_user_mapping.sgml b/doc/src/sgml/ref/drop_user_mapping.sgml
index c22dedb661a..82d5fa5dcb1 100644
--- a/doc/src/sgml/ref/drop_user_mapping.sgml
+++ b/doc/src/sgml/ref/drop_user_mapping.sgml
@@ -1,5 +1,5 @@
 <!--
-$PostgreSQL: pgsql/doc/src/sgml/ref/drop_user_mapping.sgml,v 1.1 2008/12/19 16:25:16 petere Exp $
+$PostgreSQL: pgsql/doc/src/sgml/ref/drop_user_mapping.sgml,v 1.2 2009/01/20 09:10:20 petere Exp $
 PostgreSQL documentation
 -->
 
@@ -29,8 +29,14 @@ DROP USER MAPPING [ IF EXISTS ] FOR { <replaceable class="parameter">username</r
 
   <para>
    <command>DROP USER MAPPING</command> removes an existing user
-   mapping from foreign server.  To execute this command, the current
-   user must be the owner of the server containing the mapping.
+   mapping from foreign server.
+  </para>
+
+  <para>
+   The owner of a foreign server can drop user mappings for that server
+   for any user.  Also, a user can drop a user mapping for his own
+   user name if <literal>USAGE</> privilege on the server has been
+   granted to the user.
   </para>
  </refsect1>
 
diff --git a/src/backend/catalog/information_schema.sql b/src/backend/catalog/information_schema.sql
index 5bb46eedf8a..470a454f690 100644
--- a/src/backend/catalog/information_schema.sql
+++ b/src/backend/catalog/information_schema.sql
@@ -4,7 +4,7 @@
  *
  * Copyright (c) 2003-2009, PostgreSQL Global Development Group
  *
- * $PostgreSQL: pgsql/src/backend/catalog/information_schema.sql,v 1.49 2009/01/14 21:12:09 petere Exp $
+ * $PostgreSQL: pgsql/src/backend/catalog/information_schema.sql,v 1.50 2009/01/20 09:10:20 petere Exp $
  */
 
 /*
@@ -2465,12 +2465,12 @@ CREATE VIEW _pg_foreign_servers AS
            s.srvoptions,
            CAST(current_database() AS sql_identifier) AS foreign_server_catalog,
            CAST(srvname AS sql_identifier) AS foreign_server_name,
-           w.foreign_data_wrapper_catalog,
-           w.foreign_data_wrapper_name,
+           CAST(current_database() AS sql_identifier) AS foreign_data_wrapper_catalog,
+           CAST(w.fdwname AS sql_identifier) AS foreign_data_wrapper_name,
            CAST(srvtype AS character_data) AS foreign_server_type,
            CAST(srvversion AS character_data) AS foreign_server_version,
            CAST(u.rolname AS sql_identifier) AS authorization_identifier
-    FROM pg_foreign_server s, _pg_foreign_data_wrappers w, pg_authid u
+    FROM pg_foreign_server s, pg_foreign_data_wrapper w, pg_authid u
     WHERE w.oid = s.srvfdw
           AND u.oid = s.srvowner
           AND (pg_has_role(s.srvowner, 'USAGE')
@@ -2512,9 +2512,11 @@ GRANT SELECT ON foreign_servers TO PUBLIC;
 CREATE VIEW _pg_user_mappings AS
     SELECT um.oid,
            um.umoptions,
+           um.umuser,
            CAST(COALESCE(u.rolname,'PUBLIC') AS sql_identifier ) AS authorization_identifier,
            s.foreign_server_catalog,
-           s.foreign_server_name
+           s.foreign_server_name,
+           s.authorization_identifier AS srvowner
     FROM pg_user_mapping um LEFT JOIN pg_authid u ON (u.oid = um.umuser),
          _pg_foreign_servers s
     WHERE s.oid = um.umserver;
@@ -2529,7 +2531,10 @@ CREATE VIEW user_mapping_options AS
            foreign_server_catalog,
            foreign_server_name,
            CAST((pg_options_to_table(um.umoptions)).option_name AS sql_identifier) AS option_name,
-           CAST((pg_options_to_table(um.umoptions)).option_value AS character_data) AS option_value
+           CAST(CASE WHEN (umuser <> 0 AND authorization_identifier = current_user)
+                       OR (umuser = 0 AND pg_has_role(srvowner, 'USAGE'))
+                       OR (SELECT rolsuper FROM pg_authid WHERE rolname = current_user) THEN (pg_options_to_table(um.umoptions)).option_value
+                     ELSE NULL END AS character_data) AS option_value
     FROM _pg_user_mappings um;
 
 GRANT SELECT ON user_mapping_options TO PUBLIC;
diff --git a/src/backend/commands/foreigncmds.c b/src/backend/commands/foreigncmds.c
index 17336c35f38..0967001aa3f 100644
--- a/src/backend/commands/foreigncmds.c
+++ b/src/backend/commands/foreigncmds.c
@@ -7,7 +7,7 @@
  *
  *
  * IDENTIFICATION
- *	  $PostgreSQL: pgsql/src/backend/commands/foreigncmds.c,v 1.4 2009/01/01 17:23:38 momjian Exp $
+ *	  $PostgreSQL: pgsql/src/backend/commands/foreigncmds.c,v 1.5 2009/01/20 09:10:20 petere Exp $
  *
  *-------------------------------------------------------------------------
  */
@@ -828,6 +828,33 @@ RemoveForeignServerById(Oid srvId)
 }
 
 
+/*
+ * Common routine to check permission for user-mapping-related DDL
+ * commands.  We allow server owners to operate on any mapping, and
+ * users to operate on their own mapping.
+ */
+static void
+user_mapping_ddl_aclcheck(Oid umuserid, Oid serverid, const char *servername)
+{
+	Oid			curuserid = GetUserId();
+
+	if (!pg_foreign_server_ownercheck(serverid, curuserid))
+	{
+		if (umuserid == curuserid)
+		{
+			AclResult			aclresult;
+
+			aclresult = pg_foreign_server_aclcheck(serverid, curuserid, ACL_USAGE);
+			if (aclresult != ACLCHECK_OK)
+				aclcheck_error(aclresult, ACL_KIND_FOREIGN_SERVER, servername);
+		}
+		else
+			aclcheck_error(ACLCHECK_NOT_OWNER, ACL_KIND_FOREIGN_SERVER,
+						   servername);
+	}
+}
+
+
 /*
  * Create user mapping
  */
@@ -841,24 +868,17 @@ CreateUserMapping(CreateUserMappingStmt *stmt)
 	HeapTuple			tuple;
 	Oid					useId;
 	Oid					umId;
-	Oid					ownerId;
 	ObjectAddress 		myself;
 	ObjectAddress		referenced;
 	ForeignServer	   *srv;
 	ForeignDataWrapper *fdw;
 
-	ownerId = GetUserId();
-
 	useId = GetUserOidFromMapping(stmt->username, false);
 
-	/*
-	 * Check that the server exists and that the we own it.
-	 */
+	/* Check that the server exists. */
 	srv = GetForeignServerByName(stmt->servername, false);
 
-	if (!pg_foreign_server_ownercheck(srv->serverid, ownerId))
-		aclcheck_error(ACLCHECK_NOT_OWNER, ACL_KIND_FOREIGN_SERVER,
-					   stmt->servername);
+	user_mapping_ddl_aclcheck(useId, srv->serverid, stmt->servername);
 
 	/*
 	 * Check that the user mapping is unique within server.
@@ -951,12 +971,7 @@ AlterUserMapping(AlterUserMappingStmt *stmt)
 				errmsg("user mapping \"%s\" does not exist for the server",
 					MappingUserName(useId))));
 
-	/*
-	 * Must be owner of the server to alter user mapping.
-	 */
-	if (!pg_foreign_server_ownercheck(srv->serverid, GetUserId()))
-		aclcheck_error(ACLCHECK_NOT_OWNER, ACL_KIND_FOREIGN_SERVER,
-					   stmt->servername);
+	user_mapping_ddl_aclcheck(useId, srv->serverid, stmt->servername);
 
 	tp = SearchSysCacheCopy(USERMAPPINGOID,
 							ObjectIdGetDatum(umId),
@@ -1071,14 +1086,7 @@ RemoveUserMapping(DropUserMappingStmt *stmt)
 		return;
 	}
 
-	/*
-	 * Only allow DROP if we own the server.
-	 */
-	if (!pg_foreign_server_ownercheck(srv->serverid, GetUserId()))
-	{
-		aclcheck_error(ACLCHECK_NOT_OWNER, ACL_KIND_FOREIGN_SERVER,
-					   srv->servername);
-	}
+	user_mapping_ddl_aclcheck(useId, srv->serverid, srv->servername);
 
 	/*
 	 * Do the deletion
diff --git a/src/test/regress/expected/foreign_data.out b/src/test/regress/expected/foreign_data.out
index 35dcae672b4..62d060b209a 100644
--- a/src/test/regress/expected/foreign_data.out
+++ b/src/test/regress/expected/foreign_data.out
@@ -545,7 +545,7 @@ SET ROLE regress_test_role;
 CREATE USER MAPPING FOR current_user SERVER s5;
 CREATE USER MAPPING FOR current_user SERVER s6 OPTIONS (username 'test');
 CREATE USER MAPPING FOR current_user SERVER s7;             -- ERROR
-ERROR:  must be owner of foreign server s7
+ERROR:  permission denied for foreign server s7
 CREATE USER MAPPING FOR public SERVER s8;                   -- ERROR
 ERROR:  must be owner of foreign server s8
 RESET ROLE;
@@ -736,6 +736,13 @@ SELECT * FROM information_schema.role_usage_grants WHERE object_type LIKE 'FOREI
 (2 rows)
 
 DROP USER MAPPING FOR current_user SERVER st1;
+SET ROLE regress_test_role2;
+SELECT * FROM information_schema.user_mapping_options ORDER BY 1, 2, 3, 4;
+ authorization_identifier | foreign_server_catalog | foreign_server_name | option_name | option_value 
+--------------------------+------------------------+---------------------+-------------+--------------
+ regress_test_role        | regression             | s6                  | username    | 
+(1 row)
+
 RESET ROLE;
 -- has_foreign_data_wrapper_privilege
 SELECT has_foreign_data_wrapper_privilege('regress_test_role',
@@ -932,8 +939,7 @@ ALTER SERVER s9 VERSION '1.2';                                  -- ERROR
 ERROR:  must be owner of foreign server s9
 GRANT USAGE ON FOREIGN SERVER s9 TO regress_test_role;          -- WARNING
 WARNING:  no privileges were granted for "s9"
-CREATE USER MAPPING FOR current_user SERVER s9;                 -- ERROR
-ERROR:  must be owner of foreign server s9
+CREATE USER MAPPING FOR current_user SERVER s9;
 DROP SERVER s9 CASCADE;                                         -- ERROR
 ERROR:  must be owner of foreign server s9
 RESET ROLE;
@@ -953,11 +959,12 @@ NOTICE:  drop cascades to user mapping for public
 DROP SERVER st2;
 DROP USER MAPPING FOR regress_test_role SERVER s6;
 DROP FOREIGN DATA WRAPPER foo CASCADE;
-NOTICE:  drop cascades to 4 other objects
+NOTICE:  drop cascades to 5 other objects
 DETAIL:  drop cascades to server s4
 drop cascades to user mapping for foreign_data_user
 drop cascades to server s6
 drop cascades to server s9
+drop cascades to user mapping for unprivileged_role
 DROP SERVER s8 CASCADE;
 NOTICE:  drop cascades to 2 other objects
 DETAIL:  drop cascades to user mapping for foreign_data_user
diff --git a/src/test/regress/sql/foreign_data.sql b/src/test/regress/sql/foreign_data.sql
index 1424fc68f08..c52fe912c1d 100644
--- a/src/test/regress/sql/foreign_data.sql
+++ b/src/test/regress/sql/foreign_data.sql
@@ -273,6 +273,8 @@ SELECT * FROM information_schema.user_mapping_options ORDER BY 1, 2, 3, 4;
 SELECT * FROM information_schema.usage_privileges WHERE object_type LIKE 'FOREIGN%' ORDER BY 1, 2, 3, 4, 5;
 SELECT * FROM information_schema.role_usage_grants WHERE object_type LIKE 'FOREIGN%' ORDER BY 1, 2, 3, 4, 5;
 DROP USER MAPPING FOR current_user SERVER st1;
+SET ROLE regress_test_role2;
+SELECT * FROM information_schema.user_mapping_options ORDER BY 1, 2, 3, 4;
 RESET ROLE;
 
 
@@ -365,7 +367,7 @@ GRANT USAGE ON FOREIGN SERVER s9 TO unprivileged_role;
 SET ROLE unprivileged_role;
 ALTER SERVER s9 VERSION '1.2';                                  -- ERROR
 GRANT USAGE ON FOREIGN SERVER s9 TO regress_test_role;          -- WARNING
-CREATE USER MAPPING FOR current_user SERVER s9;                 -- ERROR
+CREATE USER MAPPING FOR current_user SERVER s9;
 DROP SERVER s9 CASCADE;                                         -- ERROR
 RESET ROLE;
 
-- 
GitLab