WIP: Add CDB_Federated_Server_Unregister

This commit is contained in:
Raul Marin 2019-10-28 18:34:46 +01:00
parent eb02ca4d86
commit acf1f2dbd4
4 changed files with 137 additions and 22 deletions

View File

@ -10,7 +10,7 @@ LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
-- Produce a valid DB name for objects created for the user FDW's
CREATE OR REPLACE FUNCTION @extschema@.__CDB_FS_Object_Name(fdw_input_name NAME)
CREATE OR REPLACE FUNCTION @extschema@.__CDB_FS_Generate_Object_Name(fdw_input_name NAME)
RETURNS NAME
AS $$
DECLARE
@ -26,11 +26,19 @@ END
$$
LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE;
CREATE OR REPLACE FUNCTION @extschema@.__CDB_FS_Extract_Public_Name(fdw_stored_name NAME)
RETURNS TEXT
AS $$
SELECT right(fdw_stored_name,
char_length(fdw_stored_name::TEXT) - char_length(@extschema@.__CDB_FS_Name_Pattern()))::TEXT;
$$
LANGUAGE SQL IMMUTABLE PARALLEL SAFE;
-- List registered servers
-- TODO: Decide whether we want to show extra config (extensions, fetch_size, use_remote_estimate)s
CREATE OR REPLACE FUNCTION @extschema@.CDB_Federated_Server_List_Servers(fdw_pattern TEXT DEFAULT '%')
-- TODO: Decide whether we want to show extra config (extensions, fetch_size, use_remote_estimate)
-- TODO: Handle multiple user mappings in the same server
CREATE OR REPLACE FUNCTION @extschema@.CDB_Federated_Server_List_Servers(server TEXT DEFAULT '%')
RETURNS TABLE (
name text,
driver text,
@ -42,22 +50,22 @@ RETURNS TABLE (
)
AS $$
DECLARE
server_name text := concat(@extschema@.__CDB_FS_Name_Pattern() || fdw_pattern);
server_name text := concat(@extschema@.__CDB_FS_Name_Pattern(), server);
BEGIN
RETURN QUERY SELECT
-- Name as shown to the user
right(s.srvname, char_length(s.srvname::TEXT) - char_length(@extschema@.__CDB_FS_Name_Pattern()))::TEXT AS "Name",
@extschema@.__CDB_FS_Extract_Public_Name(s.srvname) AS "Name",
-- Which driver are we using (postgres_fdw, odbc_fdw...)
f.fdwname::text AS "Driver",
-- Read
-- Read options from pg_foreign_server
(SELECT option_value FROM pg_options_to_table(s.srvoptions) WHERE option_name LIKE 'host') AS "Host",
(SELECT option_value FROM pg_options_to_table(s.srvoptions) WHERE option_name LIKE 'port') AS "Port",
(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 user mappings
-- Read username from pg_user_mappings
(SELECT option_value FROM pg_options_to_table(u.umoptions) WHERE option_name LIKE 'user') AS "Username"
FROM pg_foreign_server s
JOIN pg_foreign_data_wrapper f ON f.oid=s.srvfdw
@ -68,3 +76,66 @@ BEGIN
END
$$
LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE;
-- Take a config jsonb and transform it to an input suitable for
-- _CDB_SetUp_User_PG_FDW_Server
CREATE OR REPLACE FUNCTION @extschema@.__CDB_FS_credentials_to_user_mapping(input_config JSONB)
RETURNS jsonb
AS $$
DECLARE
user_mapping jsonb := json_build_object(
'user_mapping',
jsonb_build_object('user', input_config->'credentials'->'username',
'password', input_config->'credentials'->'password')
);
BEGIN
RETURN (input_config - 'credentials')::jsonb || user_mapping;
END
$$
LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE;
-- Take a config jsonb as input and return it augmented with default
-- options
CREATE OR REPLACE FUNCTION @extschema@.__CDB_FS_add_default_options(input_config jsonb)
RETURNS jsonb
AS $$
DECLARE
default_options jsonb := '{
"extensions": "postgis",
"updatable": "false",
"use_remote_estimate": "true",
"fetch_size": "1000"
}';
server_config jsonb;
BEGIN
server_config := default_options || to_jsonb(input_config->'server');
RETURN jsonb_set(input_config, '{server}'::text[], server_config);
END
$$
LANGUAGE PLPGSQL IMMUTABLE PARALLEL SAFE;
CREATE OR REPLACE FUNCTION @extschema@.CDB_Federated_Server_Register_PG(server TEXT, config JSONB)
RETURNS void
AS $$
DECLARE
-- TODO: Check and handle existing servers (if needed)
final_name text := @extschema@.__CDB_FS_Generate_Object_Name(server);
final_config jsonb := @extschema@.__CDB_FS_credentials_to_user_mapping(@extschema@.__CDB_FS_add_default_options(config));
BEGIN
PERFORM @extschema@._CDB_SetUp_User_PG_FDW_Server(final_name, final_config::json);
END
$$
LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE;
CREATE OR REPLACE FUNCTION cartodb.CDB_Federated_Server_Unregister(server TEXT)
RETURNS void
AS $$
DECLARE
final_name text := cartodb.__CDB_FS_Generate_Object_Name(server);
BEGIN
-- TODO: Check if the server exists to show a nice error instead of the automatic one (which uses the implementation name)
EXECUTE 'DROP SERVER ' || quote_ident(final_name) || ' CASCADE';
END
$$
LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE;

View File

@ -184,15 +184,17 @@ RETURNS void AS $$
DECLARE
row record;
option record;
fdw_objects_name NAME := @extschema@.__CDB_User_FDW_Object_Names(fdw_input_name);
fdw_objects_name NAME := fdw_input_name;
BEGIN
-- TODO: refactor with original function
-- This function tries to be as idempotent as possible, by not creating anything more than once
-- (not even using IF NOT EXIST to avoid throwing warnings)
IF NOT EXISTS ( SELECT * FROM pg_extension WHERE extname = 'postgres_fdw') THEN
CREATE EXTENSION postgres_fdw;
RAISE NOTICE 'Created postgres_fdw EXTENSION';
RAISE EXCEPTION 'postgres_fdw extension is not installed'
USING HINT = 'Please install it with "CREATE EXTENSION postgres_fdw"';
END IF;
-- Create FDW first if it does not exist
IF NOT EXISTS ( SELECT * FROM pg_foreign_server WHERE srvname = fdw_objects_name)
THEN

View File

@ -2,28 +2,58 @@
\set QUIET on
SET client_min_messages TO error;
SET SESSION AUTHORIZATION postgres;
CREATE EXTENSION postgres_fdw;
\set QUIET off
-- Register a new server
SELECT '1.1', cartodb.CDB_Federated_Server_List_Servers();
-- SELECT '1.2', cartodb.CDB_Federated_Server_Register_PG();
-- SELECT '1.3', cartodb.CDB_Federated_Server_List_Servers();
--
SELECT '1.2', cartodb.CDB_Federated_Server_List_Servers(server := 'doesNotExist');
SELECT '1.3', cartodb.CDB_Federated_Server_Register_PG(server := 'myRemote'::text, config := '{
"server": {
"host": "localhost",
"port": @@PGPORT@@
},
"credentials": {
"username": "fdw_user",
"password": "foobarino"
}
}'::jsonb);
SELECT '1.4', cartodb.CDB_Federated_Server_List_Servers();
-- Register a second server
-- SELECT '2.1', cartodb.CDB_Federated_Server_Register_PG();
-- SELECT '2.2', cartodb.CDB_PG_Federated_Server_List_Servers();
--
SELECT '2.1', cartodb.CDB_Federated_Server_Register_PG(server := 'myRemote2'::text, config := '{
"server": {
"dbname": "fdw_target",
"host": "localhost",
"port": @@PGPORT@@,
"extensions": "postgis",
"updatable": "false",
"use_remote_estimate": "true",
"fetch_size": "1000"
},
"credentials": {
"username": "fdw_user",
"password": "foobarino"
}
}'::jsonb);
SELECT '2.2', cartodb.CDB_Federated_Server_List_Servers();
-- Re-register the second server
-- SELECT '3.1', cartodb.CDB_Federated_Server_Register_PG();
-- SELECT '3.2', cartodb.CDB_PG_Federated_Server_List_Servers();
--
-- Unregister #1
-- SELECT '4.1', cartodb.CDB_PG_Federated_Server_Unregister();
-- SELECT '4.2', cartodb.CDB_PG_Federated_Server_List_Servers();
--
SELECT '4.1', cartodb.CDB_Federated_Server_Unregister(server := 'myRemote'::text);
SELECT '4.2', cartodb.CDB_Federated_Server_List_Servers();
-- Unregister a server that doesn't exist
SELECT '5.1', cartodb.CDB_Federated_Server_Unregister(server := 'doesNotExist'::text);
SELECT '5.2', cartodb.CDB_Federated_Server_List_Servers();
-- Unregister #2
-- SELECT '5.1', cartodb.CDB_PG_Federated_Server_Unregister();
-- SELECT '5.2', cartodb.CDB_PG_Federated_Server_List_Servers();
SELECT '6.1', cartodb.CDB_Federated_Server_Unregister(server := 'myRemote2'::text);
SELECT '6.2', cartodb.CDB_Federated_Server_List_Servers();
-- Should show the appropiate output (database, read-write, user, pass)
@ -37,7 +67,7 @@ SELECT '1.1', cartodb.CDB_Federated_Server_List_Servers();
-- Cleanup
\set QUIET on
DROP EXTENSION postgres_fdw;
\set QUIET off

View File

@ -0,0 +1,12 @@
1.3|
1.4|(myRemote,postgres_fdw,localhost,5432,,read-only,fdw_user)
2.1|
2.2|(myRemote,postgres_fdw,localhost,5432,,read-only,fdw_user)
2.2|(myRemote2,postgres_fdw,localhost,5432,fdw_target,read-only,fdw_user)
4.1|
4.2|(myRemote2,postgres_fdw,localhost,5432,fdw_target,read-only,fdw_user)
ERROR: server "cdb_fs_doesNotExist" does not exist
CONTEXT: SQL statement "DROP SERVER "cdb_fs_doesNotExist" CASCADE"
PL/pgSQL function cdb_federated_server_unregister(text) line 5 at EXECUTE
5.2|(myRemote2,postgres_fdw,localhost,5432,fdw_target,read-only,fdw_user)
6.1|