diff --git a/scripts-available/CDB_FederatedServer.sql b/scripts-available/CDB_FederatedServer.sql index bf5a841..d5cfa5e 100644 --- a/scripts-available/CDB_FederatedServer.sql +++ b/scripts-available/CDB_FederatedServer.sql @@ -192,6 +192,34 @@ END $$ LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE; +-- Given an server name, returns the username used in the configuration if the caller has rights to access it +CREATE OR REPLACE FUNCTION @extschema@.__CDB_FS_get_usermapping_username(internal_server_name NAME) +RETURNS text +AS $$ +DECLARE + role_name name := @extschema@.__CDB_FS_Generate_Server_Role_Name(internal_server_name); + username text; +BEGIN + BEGIN + EXECUTE 'SET LOCAL ROLE ' || quote_ident(role_name); + EXCEPTION WHEN OTHERS THEN + RETURN NULL; + END; + + SELECT (SELECT option_value FROM pg_options_to_table(u.umoptions) WHERE option_name LIKE 'user') as name INTO username + FROM pg_foreign_server s + LEFT JOIN pg_user_mappings u + ON u.srvid = s.oid + WHERE s.srvname = internal_server_name + ORDER BY 1; + + RESET ROLE; + + RETURN username; +END +$$ +LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; + -------------------------------------------------------------------------------- -- Public functions @@ -233,7 +261,7 @@ BEGIN RAISE EXCEPTION 'postgres_fdw extension is not installed' USING HINT = 'Please install it with `CREATE EXTENSION postgres_fdw`'; END IF; - + -- We only create server and roles if the server didn't exist before IF NOT EXISTS (SELECT * FROM pg_foreign_server WHERE srvname = server_internal) THEN BEGIN @@ -345,8 +373,7 @@ BEGIN (SELECT option_value FROM pg_options_to_table(s.srvoptions) WHERE option_name LIKE 'dbname') AS "DBName", CASE WHEN (SELECT NOT option_value::boolean FROM pg_options_to_table(s.srvoptions) WHERE option_name LIKE 'updatable') THEN 'read-only' ELSE 'read-write' END AS "ReadMode", - -- Read username from pg_user_mappings - (SELECT option_value FROM pg_options_to_table(u.umoptions) WHERE option_name LIKE 'user') AS "Username" + @extschema@.__CDB_FS_get_usermapping_username(s.srvname)::text AS "Username" FROM pg_foreign_server s LEFT JOIN pg_user_mappings u ON u.srvid = s.oid diff --git a/test/CDB_FederatedServer.sql b/test/CDB_FederatedServer.sql index 1f418c2..d314790 100644 --- a/test/CDB_FederatedServer.sql +++ b/test/CDB_FederatedServer.sql @@ -175,6 +175,9 @@ SELECT '9.3', cartodb.CDB_Federated_Server_Register_PG(server => 'myRemote4'::te \echo '## Granting access to a user works' SELECT '9.5', cartodb.CDB_Federated_Server_Grant_Access(server => 'myRemote3', db_role => 'cdb_fs_tester'::name); +\c contrib_regression cdb_fs_tester +SELECT '9.55', cartodb.CDB_Federated_Server_List_Servers(); +\c contrib_regression postgres SELECT '9.6', cartodb.CDB_Federated_Server_Grant_Access(server => 'does not exist', db_role => 'cdb_fs_tester'::name); SELECT '9.7', cartodb.CDB_Federated_Server_Grant_Access(server => 'myRemote3', db_role => 'does not exist'::name); diff --git a/test/CDB_FederatedServer_expect b/test/CDB_FederatedServer_expect index f21f2cc..836646d 100644 --- a/test/CDB_FederatedServer_expect +++ b/test/CDB_FederatedServer_expect @@ -47,6 +47,9 @@ ERROR: Could not create server myRemote4: permission denied for foreign-data wr You are now connected to database "contrib_regression" as user "postgres". ## Granting access to a user works 9.5| +You are now connected to database "contrib_regression" as user "cdb_fs_tester". +9.55|(myRemote3,postgres_fdw,localhost,5432,,read-only,fdw_user) +You are now connected to database "contrib_regression" as user "postgres". ERROR: Server "does not exist" does not exist ERROR: Could not grant access on "myRemote3" to "does not exist": role "does not exist" does not exist ## Granting access again raises a notice