Compare commits

...

7 Commits

Author SHA1 Message Date
Rafa de la Torre
e9b3144390 Rename private functions
Rename __cdb_* "private" functions to __ft_*, kind of a namespace to
avoid name clashing.
2019-10-08 17:14:10 +02:00
Rafa de la Torre
df396bf41f __cdb_add_default_options function and tests 2019-10-08 17:11:31 +02:00
Rafa de la Torre
101d276f91 __cdb_credentials_to_user_mapping function & test 2019-10-08 16:16:42 +02:00
Rafa de la Torre
49efd939f6 Minimal implementation 2019-10-08 12:04:57 +02:00
Rafa de la Torre
571ccfe4d6 Simplify setup and teardown of fdw_target 2019-10-08 11:44:23 +02:00
Rafa de la Torre
253d162f6f Extract setup and teardown of fdw_target 2019-10-08 11:39:00 +02:00
Rafa de la Torre
38bed2a3b8 Skeleton for CDB_SetUp_PG_Federated_Server 2019-10-08 10:43:16 +02:00
3 changed files with 180 additions and 23 deletions

View File

@ -0,0 +1,72 @@
----------------------------------------------------------------------
-- Federated Tables management functions
----------------------------------------------------------------------
-- Take a config jsonb and transform it to an input suitable for
-- _CDB_SetUp_User_PG_FDW_Server
CREATE OR REPLACE FUNCTION @extschema@.__ft_credentials_to_user_mapping(input_config jsonb)
RETURNS jsonb
AS $$
DECLARE
user_mapping jsonb;
BEGIN
user_mapping := json_build_object('user_mapping',
jsonb_build_object(
'user', input_config->'credentials'->'username',
'password', input_config->'credentials'->'password'
)
);
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@.__ft_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;
--
-- Set up a federated server for later connection of tables/views
-- E.g:
-- SELECT cartodb.CDB_SetUp_PG_Federated_Server('amazon', '{
-- "server": {
-- "dbname": "testdb",
-- "host": "myhostname.us-east-2.rds.amazonaws.com",
-- "port": "5432"
-- },
-- "credentials": {
-- "username": "read_only_user",
-- "password": "secret"
-- }
-- }');
CREATE OR REPLACE FUNCTION @extschema@.CDB_SetUp_PG_Federated_Server(server_alias text, server_config jsonb)
RETURNS void
AS $$
DECLARE
final_config jsonb;
BEGIN
final_config := @extschema@.__ft_credentials_to_user_mapping(
@extschema@.__ft_add_default_options(server_config)
);
PERFORM cartodb._CDB_SetUp_User_PG_FDW_Server(server_alias, final_config::json);
END
$$
LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE;

View File

@ -0,0 +1 @@
../scripts-available/CDB_PG_Federated_Tables.sql

View File

@ -502,10 +502,11 @@ function test_cdb_querytables_happy_cases() {
sql postgres 'DROP SCHEMA foo;'
}
function test_foreign_tables() {
function setup_fdw_target() {
local DATABASE=fdw_target
DATABASE=fdw_target setup_database
DATABASE=fdw_target sql postgres "DO
setup_database
sql postgres "DO
\$\$
BEGIN
IF NOT EXISTS (
@ -518,19 +519,36 @@ BEGIN
END
\$\$;"
DATABASE=fdw_target sql postgres 'CREATE SCHEMA test_fdw;'
DATABASE=fdw_target sql postgres 'CREATE TABLE test_fdw.foo (a int);'
DATABASE=fdw_target sql postgres 'INSERT INTO test_fdw.foo (a) values (42);'
DATABASE=fdw_target sql postgres 'CREATE TABLE test_fdw.foo2 (a int);'
DATABASE=fdw_target sql postgres 'INSERT INTO test_fdw.foo2 (a) values (42);'
DATABASE=fdw_target sql postgres "CREATE USER fdw_user WITH PASSWORD 'foobarino';"
DATABASE=fdw_target sql postgres 'GRANT USAGE ON SCHEMA test_fdw TO fdw_user;'
DATABASE=fdw_target sql postgres 'GRANT SELECT ON TABLE test_fdw.foo TO fdw_user;'
DATABASE=fdw_target sql postgres 'GRANT SELECT ON TABLE test_fdw.foo2 TO fdw_user;'
DATABASE=fdw_target sql postgres 'GRANT SELECT ON cdb_tablemetadata_text TO fdw_user;'
sql postgres 'CREATE SCHEMA test_fdw;'
sql postgres 'CREATE TABLE test_fdw.foo (a int);'
sql postgres 'INSERT INTO test_fdw.foo (a) values (42);'
sql postgres 'CREATE TABLE test_fdw.foo2 (a int);'
sql postgres 'INSERT INTO test_fdw.foo2 (a) values (42);'
sql postgres "CREATE USER fdw_user WITH PASSWORD 'foobarino';"
sql postgres 'GRANT USAGE ON SCHEMA test_fdw TO fdw_user;'
sql postgres 'GRANT SELECT ON TABLE test_fdw.foo TO fdw_user;'
sql postgres 'GRANT SELECT ON TABLE test_fdw.foo2 TO fdw_user;'
sql postgres 'GRANT SELECT ON cdb_tablemetadata_text TO fdw_user;'
DATABASE=fdw_target sql postgres "SELECT cdb_tablemetadatatouch('test_fdw.foo'::regclass);"
DATABASE=fdw_target sql postgres "SELECT cdb_tablemetadatatouch('test_fdw.foo2'::regclass);"
sql postgres "SELECT cdb_tablemetadatatouch('test_fdw.foo'::regclass);"
sql postgres "SELECT cdb_tablemetadatatouch('test_fdw.foo2'::regclass);"
}
function tear_down_fdw_target() {
local DATABASE=fdw_target
sql postgres 'REVOKE USAGE ON SCHEMA test_fdw FROM fdw_user;'
sql postgres 'REVOKE SELECT ON test_fdw.foo FROM fdw_user;'
sql postgres 'REVOKE SELECT ON test_fdw.foo2 FROM fdw_user;'
sql postgres 'REVOKE SELECT ON cdb_tablemetadata_text FROM fdw_user;'
sql postgres 'DROP ROLE fdw_user;'
DATABASE=test_extension sql postgres "select pg_terminate_backend(pid) from pg_stat_activity where datname='fdw_target';"
DATABASE=fdw_target tear_down_database
}
function test_foreign_tables() {
setup_fdw_target
# Add PGPORT to conf if it is set
PORT_SPEC=""
@ -651,16 +669,82 @@ EOF
sql cdb_testmember_1 "SELECT cartodb.CDB_SetUp_User_PG_FDW_Table('another_user_defined_test', 'test_fdw', 'foo');"
sql postgres "SELECT cartodb._CDB_Drop_User_PG_FDW_Server('another_user_defined_test', /* force = */ true)"
tear_down_fdw_target
}
function test_federated_tables() {
setup_fdw_target
# Federated server configuration for tests
read -d '' federated_server_config <<- EOF
{
"server": {
"dbname": "fdw_target",
"host": "localhost",
"port": ${PGPORT:-5432}
},
"credentials": {
"username": "fdw_user",
"password": "foobarino"
}
}
EOF
# Unit-test __ft_credentials_to_user_mapping
read -d '' expected_user_mapping <<- EOF
{
"server": {
"dbname": "fdw_target",
"host": "localhost",
"port": ${PGPORT:-5432}
},
"user_mapping": {
"user": "fdw_user",
"password": "foobarino"
}
}
EOF
sql postgres "SELECT cartodb.__ft_credentials_to_user_mapping('$federated_server_config') = '$expected_user_mapping'" \
should 't'
# Unit-test __ft_add_default_options
read -d '' expected_default_options <<- EOF
{
"server": {
"dbname": "fdw_target",
"host": "localhost",
"port": ${PGPORT:-5432},
"extensions": "postgis",
"updatable": "false",
"use_remote_estimate": "true",
"fetch_size": "1000"
},
"credentials": {
"username": "fdw_user",
"password": "foobarino"
}
}
EOF
sql postgres "SELECT cartodb.__ft_add_default_options('$federated_server_config') = '$expected_default_options'" \
should 't'
# There must be a function with the expected interface
sql postgres "SELECT cartodb.CDB_SetUp_PG_Federated_Server('my_server', '$federated_server_config');"
# It must be possible to use the created server and user mapping
# to connect and use a foreign table
sql postgres 'GRANT "cdb_fdw_my_server" TO cdb_testmember_1 WITH ADMIN OPTION;'
sql cdb_testmember_1 "SELECT cartodb.CDB_SetUp_User_PG_FDW_Table('my_server', 'test_fdw', 'foo');"
sql cdb_testmember_1 'SELECT * from "cdb_fdw_my_server".foo;'
sql cdb_testmember_1 'SELECT a from "cdb_fdw_my_server".foo LIMIT 1;' should 42
# It must apply some sensible defaults
sql postgres "SELECT srvoptions FROM pg_foreign_server WHERE srvname = 'cdb_fdw_my_server'" \
should '{host=localhost,port=5432,dbname=fdw_target,updatable=false,extensions=postgis,fetch_size=1000,use_remote_estimate=true}'
# Tear down
DATABASE=fdw_target sql postgres 'REVOKE USAGE ON SCHEMA test_fdw FROM fdw_user;'
DATABASE=fdw_target sql postgres 'REVOKE SELECT ON test_fdw.foo FROM fdw_user;'
DATABASE=fdw_target sql postgres 'REVOKE SELECT ON test_fdw.foo2 FROM fdw_user;'
DATABASE=fdw_target sql postgres 'REVOKE SELECT ON cdb_tablemetadata_text FROM fdw_user;'
DATABASE=fdw_target sql postgres 'DROP ROLE fdw_user;'
sql postgres "select pg_terminate_backend(pid) from pg_stat_activity where datname='fdw_target';"
DATABASE=fdw_target tear_down_database
sql postgres "SELECT cartodb._CDB_Drop_User_PG_FDW_Server('my_server', /* force = */ true)"
tear_down_fdw_target
}
function test_cdb_catalog_basic_node() {