From 01258530ff4a9e17446afd3d18ffd3e1df139bc2 Mon Sep 17 00:00:00 2001 From: Raul Marin Date: Wed, 6 Nov 2019 17:04:11 +0100 Subject: [PATCH] Federated Server: Unify remote table listing - Removes DB_Federated_Server_List_Registered_Tables in favor of CDB_Federated_Server_List_Remote_Tables that now returns both registered and unregistered tables and, when they are registered, the information about the associated view --- .../CDB_FederatedServerListRemote.sql | 110 ++++++++---- .../CDB_FederatedServerTables.sql | 169 ++++++++++++------ test/CDB_FederatedServerListRemote.sql | 1 - test/CDB_FederatedServerListRemote_expect | 45 ++--- test/CDB_FederatedServerTables.sql | 32 ++-- test/CDB_FederatedServerTables_expect | 49 +++-- 6 files changed, 257 insertions(+), 149 deletions(-) diff --git a/scripts-available/CDB_FederatedServerListRemote.sql b/scripts-available/CDB_FederatedServerListRemote.sql index d8932c0..845660f 100644 --- a/scripts-available/CDB_FederatedServerListRemote.sql +++ b/scripts-available/CDB_FederatedServerListRemote.sql @@ -30,7 +30,8 @@ BEGIN WHERE relnamespace = (SELECT oid FROM pg_namespace WHERE nspname = local_schema) AND relname = remote_table ) THEN - EXECUTE format('IMPORT FOREIGN SCHEMA %I LIMIT TO (%I) FROM SERVER %I INTO %I', inf_schema, remote_table, server_internal, local_schema); + EXECUTE format('IMPORT FOREIGN SCHEMA %I LIMIT TO (%I) FROM SERVER %I INTO %I', + inf_schema, remote_table, server_internal, local_schema); END IF; -- Return the result we're interested in. Exclude toast and temp schemas @@ -49,7 +50,7 @@ $$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; -- --- List the tables from a remote PG schema +-- List the names of the tables in a remote PG schema -- CREATE OR REPLACE FUNCTION @extschema@.__CDB_FS_List_Foreign_Tables_PG(server_internal name, remote_schema name) RETURNS TABLE(remote_table name) @@ -74,10 +75,10 @@ BEGIN WHERE relnamespace = (SELECT oid FROM pg_namespace WHERE nspname = local_schema) AND relname = remote_table ) THEN - EXECUTE format('IMPORT FOREIGN SCHEMA %I LIMIT TO (%I) FROM SERVER %I INTO %I', inf_schema, remote_table, server_internal, local_schema); + EXECUTE format('IMPORT FOREIGN SCHEMA %I LIMIT TO (%I) FROM SERVER %I INTO %I', + inf_schema, remote_table, server_internal, local_schema); END IF; - -- Return the result we're interested in -- Note: in this context, schema names are not to be quoted RETURN QUERY EXECUTE format($q$ SELECT table_name::name AS remote_table FROM %I.%I WHERE table_schema = '%s' ORDER BY table_name @@ -88,10 +89,10 @@ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; -- --- List the columns from a remote PG table +-- List the columns in a remote PG schema -- -CREATE OR REPLACE FUNCTION @extschema@.__CDB_FS_List_Foreign_Columns_PG(server_internal name, remote_schema name, remote_table name) -RETURNS TABLE(column_name name, column_type text) +CREATE OR REPLACE FUNCTION @extschema@.__CDB_FS_List_Foreign_Columns_PG(server_internal name, remote_schema name) +RETURNS TABLE(table_name name, column_name name, column_type text) AS $func$ DECLARE -- Import `columns` from the information schema @@ -112,30 +113,37 @@ BEGIN WHERE relnamespace = (SELECT oid FROM pg_namespace WHERE nspname = local_schema) AND relname = remote_col_table ) THEN - EXECUTE format('IMPORT FOREIGN SCHEMA %I LIMIT TO (%I) FROM SERVER %I INTO %I', inf_schema, remote_col_table, server_internal, local_schema); + EXECUTE format('IMPORT FOREIGN SCHEMA %I LIMIT TO (%I) FROM SERVER %I INTO %I', + inf_schema, remote_col_table, server_internal, local_schema); END IF; - -- Return the result we're interested in - -- Note: in this context, remote schema and remote table names are not to be quoted + -- Note: in this context, schema names are not to be quoted + -- We join with the geometry columns to change the type `USER-DEFINED` + -- by its appropiate geometry and srid RETURN QUERY EXECUTE format($q$ SELECT - a.column_name::name, COALESCE(b.column_type, a.data_type)::TEXT as column_type - FROM %I.%I a - LEFT JOIN @extschema@.__CDB_FS_List_Foreign_Geometry_Columns_PG('%s', '%s', '%s') b ON a.column_name = b.column_name - WHERE table_schema = '%s' AND table_name = '%s' - ORDER BY column_name$q$, + a.table_name::name, + a.column_name::name, + COALESCE(b.column_type, a.data_type)::TEXT as column_type + FROM + %I.%I a + LEFT JOIN + @extschema@.__CDB_FS_List_Foreign_Geometry_Columns_PG('%s', '%s') b + ON a.table_name = b.table_name AND a.column_name = b.column_name + WHERE table_schema = '%s' + ORDER BY a.table_name, a.column_name $q$, local_schema, remote_col_table, - server_internal, remote_schema, remote_table, - remote_schema, remote_table); + server_internal, remote_schema, + remote_schema); END $func$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; -- --- List the columns from a remote PG table +-- List the geometry columns in a remote PG schema -- -CREATE OR REPLACE FUNCTION @extschema@.__CDB_FS_List_Foreign_Geometry_Columns_PG(server_internal name, remote_schema name, remote_table name, postgis_schema name DEFAULT 'public') -RETURNS TABLE(column_name name, column_type text) +CREATE OR REPLACE FUNCTION @extschema@.__CDB_FS_List_Foreign_Geometry_Columns_PG(server_internal name, remote_schema name, postgis_schema name DEFAULT 'public') +RETURNS TABLE(table_name name, column_name name, column_type text) AS $func$ DECLARE -- Import `geometry_columns` and `geography_columns` from the postgis schema @@ -159,21 +167,22 @@ BEGIN BEGIN -- Note: We return both the type and srid as the type RETURN QUERY EXECUTE format($q$ - SELECT f_geometry_column::NAME as column_name, - type::TEXT || ',' || srid::TEXT as column_type - FROM - ( - SELECT * FROM %I.%I UNION ALL SELECT * FROM %I.%I - ) _geo_views - WHERE - f_table_schema = '%s' AND - f_table_name = '%s' + SELECT + f_table_name::NAME as table_name, + f_geometry_column::NAME as column_name, + type::TEXT || ',' || srid::TEXT as column_type + FROM + ( + SELECT * FROM %I.%I UNION ALL SELECT * FROM %I.%I + ) _geo_views + WHERE f_table_schema = '%s' $q$, local_schema, remote_geometry_view, local_schema, remote_geography_view, - remote_schema, remote_table); + remote_schema); EXCEPTION WHEN OTHERS THEN - RAISE NOTICE 'Could not find Postgis installation in the remote "%" schema', postgis_schema; + RAISE INFO 'Could not find Postgis installation in the remote "%" schema in server "%"', + postgis_schema, @extschema@.__CDB_FS_Extract_Server_Name(server_internal); RETURN; END; END @@ -207,9 +216,18 @@ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; -- -- List remote tables in a federated server that the current user has access to. +-- For registered tables it returns also the associated configuration -- CREATE OR REPLACE FUNCTION @extschema@.CDB_Federated_Server_List_Remote_Tables(server TEXT, remote_schema TEXT) -RETURNS TABLE(remote_table name) +RETURNS TABLE( + registered boolean, + remote_table TEXT, + local_qualified_name TEXT, + id_column_name TEXT, + geom_column_name TEXT, + webmercator_column_name TEXT, + columns JSON + ) AS $$ DECLARE server_internal name := @extschema@.__CDB_FS_Generate_Server_Name(input_name := server, check_existence := true); @@ -217,7 +235,29 @@ DECLARE BEGIN CASE server_type WHEN 'postgres_fdw' THEN - RETURN QUERY SELECT @extschema@.__CDB_FS_List_Foreign_Tables_PG(server_internal, remote_schema); + RETURN QUERY + SELECT + coalesce(registered_tables.registered, false)::boolean as registered, + foreign_tables.remote_table::text as remote_table, + registered_tables.local_qualified_name as local_qualified_name, + registered_tables.id_column_name as id_column_name, + registered_tables.geom_column_name as geom_column_name, + registered_tables.webmercator_column_name as webmercator_column_name, + remote_columns.columns as columns + FROM + @extschema@.__CDB_FS_List_Foreign_Tables_PG(server_internal, remote_schema) foreign_tables + LEFT JOIN + @extschema@.__CDB_FS_List_Registered_Tables(server_internal, remote_schema) registered_tables + ON foreign_tables.remote_table = registered_tables.remote_table + LEFT JOIN + ( -- Extract and group columns with their remote table + SELECT table_name, + json_agg(json_build_object('Name', column_name, 'Type', column_type)) as columns + FROM @extschema@.__CDB_FS_List_Foreign_Columns_PG(server_internal, remote_schema) + GROUP BY table_name + ) remote_columns + ON foreign_tables.remote_table = remote_columns.table_name + ORDER BY foreign_tables.remote_table; ELSE RAISE EXCEPTION 'Not implemented server type % for remote server %', server_type, remote_server; END CASE; @@ -232,7 +272,7 @@ CREATE OR REPLACE FUNCTION @extschema@.CDB_Federated_Server_List_Remote_Columns( server TEXT, remote_schema TEXT, remote_table TEXT) -RETURNS TABLE(column_name name, column_type text) +RETURNS TABLE(column_n name, column_t text) AS $$ DECLARE server_internal name := @extschema@.__CDB_FS_Generate_Server_Name(input_name := server, check_existence := true); @@ -244,7 +284,7 @@ BEGIN CASE server_type WHEN 'postgres_fdw' THEN - RETURN QUERY SELECT * FROM @extschema@.__CDB_FS_List_Foreign_Columns_PG(server_internal, remote_schema, remote_table); + RETURN QUERY SELECT column_name, column_type FROM @extschema@.__CDB_FS_List_Foreign_Columns_PG(server_internal, remote_schema) where table_name = remote_table; ELSE RAISE EXCEPTION 'Not implemented server type % for remote server %', server_type, remote_server; END CASE; diff --git a/scripts-available/CDB_FederatedServerTables.sql b/scripts-available/CDB_FederatedServerTables.sql index 4cf3afe..11497a3 100644 --- a/scripts-available/CDB_FederatedServerTables.sql +++ b/scripts-available/CDB_FederatedServerTables.sql @@ -18,7 +18,7 @@ BEGIN RETURN FOUND; END $$ -LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; +LANGUAGE PLPGSQL STABLE PARALLEL UNSAFE; -- -- Checks if a column is of geometry type @@ -34,7 +34,7 @@ BEGIN RETURN FOUND; END $$ -LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; +LANGUAGE PLPGSQL STABLE PARALLEL UNSAFE; -- -- Returns the name of all the columns from a table @@ -55,7 +55,108 @@ AS $$ WHERE c.oid = input_table::oid ) ORDER BY a.attnum; -$$ LANGUAGE SQL; +$$ LANGUAGE SQL STABLE PARALLEL UNSAFE; + +-- +-- Returns the id column from a view definition +-- +CREATE OR REPLACE FUNCTION @extschema@.__CDB_FS_Get_View_id_column(view_def TEXT) +RETURNS TEXT +AS $$ + WITH column_definitions AS + ( + SELECT regexp_split_to_array(regexp_split_to_table(view_def, '\n'), ' ') AS col_def + ) + SELECT split_part(col_def[array_length(col_def, 1) - 2], '.', 2) + FROM column_definitions where col_def[array_length(col_def, 1)] = 'cartodb_id,' + LIMIT 1; +$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE; + +-- +-- Returns the geom column from a view definition +-- +CREATE OR REPLACE FUNCTION @extschema@.__CDB_FS_Get_View_geom_column(view_def TEXT) +RETURNS TEXT +AS $$ + WITH column_definitions AS + ( + SELECT regexp_split_to_array(regexp_split_to_table(view_def, '\n'), ' ') AS col_def + ) + SELECT trim(trailing ',' FROM split_part( + CASE WHEN col_def[array_length(col_def, 1) - 2] = '4326)' THEN col_def[array_length(col_def, 1) - 3] + ELSE col_def[array_length(col_def, 1) - 2] + END, '.', 2)) + FROM column_definitions + WHERE col_def[array_length(col_def, 1)] = 'the_geom,' + LIMIT 1; +$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE; + +-- +-- Returns the webmercatorcolumn from a view definition +-- +CREATE OR REPLACE FUNCTION @extschema@.__CDB_FS_Get_View_webmercator_column(view_def TEXT) +RETURNS TEXT +AS $$ + WITH column_definitions AS + ( + SELECT regexp_split_to_array(regexp_split_to_table(view_def, '\n'), ' ') AS col_def + ) + SELECT trim(trailing ',' FROM split_part( + CASE WHEN col_def[array_length(col_def, 1) - 2] = '3857)' THEN col_def[array_length(col_def, 1) - 3] + ELSE col_def[array_length(col_def, 1) - 2] + END, '.', 2)) + FROM column_definitions + WHERE col_def[array_length(col_def, 1)] = 'the_geom_webmercator,' + LIMIT 1; +$$ LANGUAGE SQL IMMUTABLE PARALLEL SAFE; + + +-- +-- List all registered tables in a server + schema +-- +CREATE OR REPLACE FUNCTION @extschema@.__CDB_FS_List_Registered_Tables( + server_internal NAME, + remote_schema TEXT + ) +RETURNS TABLE( + registered boolean, + remote_table TEXT, + local_qualified_name TEXT, + id_column_name TEXT, + geom_column_name TEXT, + webmercator_column_name TEXT + ) +AS $$ +DECLARE + local_schema name := @extschema@.__CDB_FS_Create_Schema(server_internal, remote_schema); +BEGIN + RETURN QUERY SELECT + true as registered, + source_table::text as remote_table, + format('%I.%I', dependent_schema, dependent_view)::text as local_qualified_name, + @extschema@.__CDB_FS_Get_View_id_column(view_definition) as id_column_name, + @extschema@.__CDB_FS_Get_View_geom_column(view_definition) as geom_column_name, + @extschema@.__CDB_FS_Get_View_webmercator_column(view_definition) as webmercator_column_name + FROM + ( + SELECT DISTINCT + dependent_ns.nspname as dependent_schema, + dependent_view.relname as dependent_view, + source_table.relname as source_table, + pg_get_viewdef(dependent_view.oid) as view_definition + FROM pg_depend + JOIN pg_rewrite ON pg_depend.objid = pg_rewrite.oid + JOIN pg_class as dependent_view ON pg_rewrite.ev_class = dependent_view.oid + JOIN pg_class as source_table ON pg_depend.refobjid = source_table.oid + JOIN pg_namespace dependent_ns ON dependent_ns.oid = dependent_view.relnamespace + JOIN pg_namespace source_ns ON source_ns.oid = source_table.relnamespace + WHERE + source_ns.nspname = local_schema + ORDER BY 1,2 + ) _aux; +END +$$ +LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; -------------------------------------------------------------------------------- @@ -119,15 +220,22 @@ BEGIN -- Import the foreign table -- Drop the old view / table if there was one - IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = local_schema AND table_name = remote_table) THEN + IF EXISTS (SELECT 1 FROM information_schema.tables WHERE table_schema = local_schema AND table_name = remote_table) THEN EXECUTE @extschema@.CDB_Federated_Table_Unregister(server, remote_schema, remote_table); END IF; - EXECUTE FORMAT ('IMPORT FOREIGN SCHEMA %I LIMIT TO (%I) FROM SERVER %I INTO %I;', remote_schema, remote_table, server_internal, local_schema); - src_table := format('%I.%I', local_schema, remote_table); - - --- Grant SELECT to fdw role (TODO: Re-enable if needed) - --- EXECUTE FORMAT ('GRANT SELECT ON %I.%I TO %I;', fdw_objects_name, table_name, fdw_objects_name); + BEGIN + EXECUTE FORMAT('IMPORT FOREIGN SCHEMA %I LIMIT TO (%I) FROM SERVER %I INTO %I;', + remote_schema, remote_table, server_internal, local_schema); + EXCEPTION WHEN OTHERS THEN + RAISE EXCEPTION 'Could not import schema "%" of server "%"', remote_schema, server; + END; + BEGIN + src_table := format('%I.%I', local_schema, remote_table); + EXCEPTION WHEN OTHERS THEN + RAISE EXCEPTION 'Could not import table "%.%" of server "%"', remote_schema, remote_table, server; + END; + -- Check id_column is numeric IF NOT @extschema@.__CDB_FS_Column_Is_Integer(src_table, id_column) THEN RAISE EXCEPTION 'non integer id_column "%"', id_column; @@ -155,7 +263,7 @@ BEGIN geom_expression := format('t.%I AS the_geom', geom_column); ELSE -- It needs an ST_Transform to 4326 - geom_expression := format('@postgisschema@.ST_Transform(t.%I, 4326) AS the_geom', geom_column); + geom_expression := format('@postgisschema@.ST_Transform(t.%I,4326) AS the_geom', geom_column); END IF; IF webmercator_column IS NULL @@ -166,7 +274,7 @@ BEGIN webmercator_expression := format('t.%I AS the_geom_webmercator', webmercator_column); ELSE -- It needs an ST_Transform to 3857 - webmercator_expression := format('@postgisschema@.ST_Transform(t.%I, 3857) AS the_geom_webmercator', webmercator_column); + webmercator_expression := format('@postgisschema@.ST_Transform(t.%I,3857) AS the_geom_webmercator', webmercator_column); END IF; -- CARTO columns expressions @@ -192,9 +300,6 @@ BEGIN WHEN OTHERS THEN RAISE EXCEPTION 'Could not import table "%" as "%": %', remote_table, local_name, SQLERRM; END; - - -- TODO: Handle this Grant perms to the view - -- EXECUTE format('GRANT SELECT ON %I TO %s', table_name, fdw_objects_name); END $$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; @@ -217,39 +322,3 @@ BEGIN END $$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; - --- --- List all registered tables in a server + schema --- -CREATE OR REPLACE FUNCTION @extschema@.CDB_Federated_Server_List_Registered_Tables( - server TEXT, - remote_schema TEXT - ) -RETURNS TABLE(remote_name TEXT, local_name TEXT) -AS $$ -DECLARE - server_internal name := @extschema@.__CDB_FS_Generate_Server_Name(input_name := server, check_existence := false); - local_schema name := @extschema@.__CDB_FS_Create_Schema(server_internal, remote_schema); -BEGIN - RETURN QUERY SELECT - source_table::text as remote_table, - format('%I.%I', dependent_schema, dependent_view)::text as local_view - FROM - ( - SELECT DISTINCT - dependent_ns.nspname as dependent_schema, - dependent_view.relname as dependent_view, - source_table.relname as source_table - FROM pg_depend - JOIN pg_rewrite ON pg_depend.objid = pg_rewrite.oid - JOIN pg_class as dependent_view ON pg_rewrite.ev_class = dependent_view.oid - JOIN pg_class as source_table ON pg_depend.refobjid = source_table.oid - JOIN pg_namespace dependent_ns ON dependent_ns.oid = dependent_view.relnamespace - JOIN pg_namespace source_ns ON source_ns.oid = source_table.relnamespace - WHERE - source_ns.nspname = local_schema - ORDER BY 1,2 - ) _aux; -END -$$ -LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE; diff --git a/test/CDB_FederatedServerListRemote.sql b/test/CDB_FederatedServerListRemote.sql index b5372f4..9c937e1 100644 --- a/test/CDB_FederatedServerListRemote.sql +++ b/test/CDB_FederatedServerListRemote.sql @@ -4,7 +4,6 @@ \set QUIET on SET client_min_messages TO error; \set VERBOSITY terse -SET SESSION AUTHORIZATION postgres; CREATE EXTENSION postgres_fdw; CREATE ROLE cdb_fs_tester LOGIN PASSWORD 'cdb_fs_passwd'; diff --git a/test/CDB_FederatedServerListRemote_expect b/test/CDB_FederatedServerListRemote_expect index 70b63b3..244203c 100644 --- a/test/CDB_FederatedServerListRemote_expect +++ b/test/CDB_FederatedServerListRemote_expect @@ -31,10 +31,11 @@ You are now connected to database "contrib_regression" as user "cdb_fs_tester". ERROR: Not enough permissions to access the server "loopback" You are now connected to database "contrib_regression" as user "postgres". ## Test listing of remote tables (sunny day) -T 1 -T 2 -T 3 -T 4 +INFO: Could not find Postgis installation in the remote "public" schema in server "loopback" +f|T 1|||||[{"Name" : "C 1", "Type" : "integer"}, {"Name" : "c2", "Type" : "integer"}, {"Name" : "c3", "Type" : "text"}, {"Name" : "c4", "Type" : "timestamp with time zone"}, {"Name" : "c5", "Type" : "timestamp without time zone"}, {"Name" : "c6", "Type" : "character varying"}, {"Name" : "c7", "Type" : "character"}, {"Name" : "c8", "Type" : "USER-DEFINED"}] +f|T 2|||||[{"Name" : "c1", "Type" : "integer"}, {"Name" : "c2", "Type" : "text"}] +f|T 3|||||[{"Name" : "c1", "Type" : "integer"}, {"Name" : "c2", "Type" : "integer"}, {"Name" : "c3", "Type" : "text"}] +f|T 4|||||[{"Name" : "c1", "Type" : "integer"}, {"Name" : "c2", "Type" : "integer"}, {"Name" : "c3", "Type" : "text"}] ## Test listing of remote tables without permissions after the first instantiation (rainy day) You are now connected to database "contrib_regression" as user "cdb_fs_tester". ERROR: Not enough permissions to access the server "loopback" @@ -42,10 +43,11 @@ You are now connected to database "contrib_regression" as user "postgres". ## Test listing of remote tables with permissions (sunny day) You are now connected to database "contrib_regression" as user "cdb_fs_tester". -T 1 -T 2 -T 3 -T 4 +INFO: Could not find Postgis installation in the remote "public" schema in server "loopback" +f|T 1|||||[{"Name" : "C 1", "Type" : "integer"}, {"Name" : "c2", "Type" : "integer"}, {"Name" : "c3", "Type" : "text"}, {"Name" : "c4", "Type" : "timestamp with time zone"}, {"Name" : "c5", "Type" : "timestamp without time zone"}, {"Name" : "c6", "Type" : "character varying"}, {"Name" : "c7", "Type" : "character"}, {"Name" : "c8", "Type" : "USER-DEFINED"}] +f|T 2|||||[{"Name" : "c1", "Type" : "integer"}, {"Name" : "c2", "Type" : "text"}] +f|T 3|||||[{"Name" : "c1", "Type" : "integer"}, {"Name" : "c2", "Type" : "integer"}, {"Name" : "c3", "Type" : "text"}] +f|T 4|||||[{"Name" : "c1", "Type" : "integer"}, {"Name" : "c2", "Type" : "integer"}, {"Name" : "c3", "Type" : "text"}] You are now connected to database "contrib_regression" as user "postgres". ## Test listing of remote tables without permissions after revoking access (rainy day) @@ -60,7 +62,7 @@ You are now connected to database "contrib_regression" as user "cdb_fs_tester". ERROR: Not enough permissions to access the server "loopback" You are now connected to database "contrib_regression" as user "postgres". ## Test listing of remote columns (sunny day) -NOTICE: Could not find Postgis installation in the remote "public" schema +INFO: Could not find Postgis installation in the remote "public" schema in server "loopback" C 1|integer c2|integer c3|text @@ -76,7 +78,7 @@ You are now connected to database "contrib_regression" as user "postgres". ## Test listing of remote columns with permissions (sunny day) You are now connected to database "contrib_regression" as user "cdb_fs_tester". -NOTICE: Could not find Postgis installation in the remote "public" schema +INFO: Could not find Postgis installation in the remote "public" schema in server "loopback" C 1|integer c2|integer c3|text @@ -95,6 +97,7 @@ You are now connected to database "contrib_regression" as user "postgres". ERROR: Server "Does Not Exist" does not exist ## Test listing of remote columns (rainy day): Remote schema does not exist ## Test listing of remote columns (rainy day): Remote table does not exist +INFO: Could not find Postgis installation in the remote "public" schema in server "loopback" ## Test listing of remote columns (rainy day): Remote table is NULL ERROR: Remote table name cannot be NULL ## Test listing of remote objects with permissions (sunny day) @@ -103,11 +106,12 @@ You are now connected to database "contrib_regression" as user "cdb_fs_tester2". S 1 information_schema public -T 1 -T 2 -T 3 -T 4 -NOTICE: Could not find Postgis installation in the remote "public" schema +INFO: Could not find Postgis installation in the remote "public" schema in server "loopback2" +f|T 1|||||[{"Name" : "C 1", "Type" : "integer"}, {"Name" : "c2", "Type" : "integer"}, {"Name" : "c3", "Type" : "text"}, {"Name" : "c4", "Type" : "timestamp with time zone"}, {"Name" : "c5", "Type" : "timestamp without time zone"}, {"Name" : "c6", "Type" : "character varying"}, {"Name" : "c7", "Type" : "character"}, {"Name" : "c8", "Type" : "USER-DEFINED"}] +f|T 2|||||[{"Name" : "c1", "Type" : "integer"}, {"Name" : "c2", "Type" : "text"}] +f|T 3|||||[{"Name" : "c1", "Type" : "integer"}, {"Name" : "c2", "Type" : "integer"}, {"Name" : "c3", "Type" : "text"}] +f|T 4|||||[{"Name" : "c1", "Type" : "integer"}, {"Name" : "c2", "Type" : "integer"}, {"Name" : "c3", "Type" : "text"}] +INFO: Could not find Postgis installation in the remote "public" schema in server "loopback2" C 1|integer c2|integer c3|text @@ -126,11 +130,12 @@ You are now connected to database "contrib_regression" as user "cdb_fs_tester". S 1 information_schema public -T 1 -T 2 -T 3 -T 4 -NOTICE: Could not find Postgis installation in the remote "public" schema +INFO: Could not find Postgis installation in the remote "public" schema in server "loopback2" +f|T 1|||||[{"Name" : "C 1", "Type" : "integer"}, {"Name" : "c2", "Type" : "integer"}, {"Name" : "c3", "Type" : "text"}, {"Name" : "c4", "Type" : "timestamp with time zone"}, {"Name" : "c5", "Type" : "timestamp without time zone"}, {"Name" : "c6", "Type" : "character varying"}, {"Name" : "c7", "Type" : "character"}, {"Name" : "c8", "Type" : "USER-DEFINED"}] +f|T 2|||||[{"Name" : "c1", "Type" : "integer"}, {"Name" : "c2", "Type" : "text"}] +f|T 3|||||[{"Name" : "c1", "Type" : "integer"}, {"Name" : "c2", "Type" : "integer"}, {"Name" : "c3", "Type" : "text"}] +f|T 4|||||[{"Name" : "c1", "Type" : "integer"}, {"Name" : "c2", "Type" : "integer"}, {"Name" : "c3", "Type" : "text"}] +INFO: Could not find Postgis installation in the remote "public" schema in server "loopback2" C 1|integer c2|integer c3|text diff --git a/test/CDB_FederatedServerTables.sql b/test/CDB_FederatedServerTables.sql index 8baccb3..4200a4f 100644 --- a/test/CDB_FederatedServerTables.sql +++ b/test/CDB_FederatedServerTables.sql @@ -5,7 +5,6 @@ SET client_min_messages TO error; \set VERBOSITY terse -SET SESSION AUTHORIZATION postgres; CREATE EXTENSION postgres_fdw; -- We create a username following the same steps as organization members @@ -72,10 +71,8 @@ SELECT 'R1', cartodb.CDB_Federated_Table_Register( geom_column => 'geom' ); -SELECT 'V1', pg_get_viewdef('remote_geom'); SELECT 'S1', cartodb_id, ST_AsText(the_geom), another_field FROM remote_geom; - -Select 'list_remotes1', CDB_Federated_Server_List_Registered_Tables( +Select * FROM CDB_Federated_Server_List_Remote_Tables( server => 'loopback', remote_schema => 'remote_schema' ); @@ -91,29 +88,28 @@ SELECT 'R2', cartodb.CDB_Federated_Table_Register( local_name => 'myFullTable' ); -SELECT 'V2', pg_get_viewdef('"myFullTable"'); SELECT 'S2', cartodb_id, ST_AsText(the_geom), another_field FROM "myFullTable"; - -Select 'list_remotes2', CDB_Federated_Server_List_Registered_Tables( +Select * FROM CDB_Federated_Server_List_Remote_Tables( server => 'loopback', remote_schema => 'remote_schema' ); - \echo '## Re-registering a table works' SELECT 'R3', cartodb.CDB_Federated_Table_Register( server => 'loopback', remote_schema => 'remote_schema', remote_table => 'remote_geom2', id_column => 'id', - geom_column => 'geom', + -- Switch geom and geom_column on purpose to force ST_Transform to be used + geom_column => 'geom_mercator', + webmercator_column => 'geom', local_name => 'different_name' ); -- The old view should dissapear -SELECT 'S3_old', cartodb_id, ST_AsText(the_geom), another_field FROM "myFullTable"; +SELECT 'S3_old', cartodb_id, another_field FROM "myFullTable"; -- And the new appear -SELECT 'S3_new', cartodb_id, ST_AsText(the_geom), another_field FROM different_name; +SELECT 'S3_new', cartodb_id, another_field FROM different_name; \echo '## Unregistering works' -- Deregistering the first table @@ -125,7 +121,7 @@ SELECT 'U1', CDB_Federated_Table_Unregister( -- Selecting from the created view should fail now SELECT 'UCheck1', cartodb_id, ST_AsText(the_geom), another_field FROM remote_geom; -Select 'list_remotes3', CDB_Federated_Server_List_Registered_Tables( +Select * FROM CDB_Federated_Server_List_Remote_Tables( server => 'loopback', remote_schema => 'remote_schema' ); @@ -296,8 +292,8 @@ SELECT cartodb.CDB_Federated_Table_Register( geom_column => 'geom', local_name => 'localtable'); -\echo '## Listing registered tables does not work without permissions' -Select CDB_Federated_Server_List_Registered_Tables(server => 'loopback', remote_schema => 'remote_schema'); +\echo '## Listing remote tables does not work without permissions' +Select * FROM CDB_Federated_Server_List_Remote_Tables(server => 'loopback', remote_schema => 'remote_schema'); \echo '## Registering tables works with granted permissions' \c contrib_regression postgres @@ -311,8 +307,8 @@ SELECT cartodb.CDB_Federated_Table_Register( geom_column => 'geom', local_name => 'localtable'); -\echo '## Listing registered tables works with granted permissions' -Select CDB_Federated_Server_List_Registered_Tables(server => 'loopback', remote_schema => 'remote_schema'); +\echo '## Listing remote tables works with granted permissions' +Select * FROM CDB_Federated_Server_List_Remote_Tables(server => 'loopback', remote_schema => 'remote_schema'); \echo '## Selecting from a registered table with granted permissions works' Select cartodb_id, ST_AsText(the_geom) from localtable; @@ -350,7 +346,7 @@ SELECT cartodb.CDB_Federated_Server_Grant_Access(server := 'loopback', db_role : \c contrib_regression postgres SELECT cartodb.CDB_Federated_Server_Grant_Access(server := 'loopback', db_role := 'cdb_fs_tester2'::name); \c contrib_regression cdb_fs_tester2 -Select CDB_Federated_Server_List_Registered_Tables(server => 'loopback', remote_schema => 'remote_schema'); +Select * FROM CDB_Federated_Server_List_Remote_Tables(server => 'loopback', remote_schema => 'remote_schema'); Select cartodb_id, ST_AsText(the_geom) from localtable; \echo '## A different user can unregister a table' @@ -359,7 +355,7 @@ SELECT CDB_Federated_Table_Unregister( remote_schema => 'remote_schema', remote_table => 'remote_geom' ); -Select CDB_Federated_Server_List_Registered_Tables(server => 'loopback', remote_schema => 'remote_schema'); +Select * FROM CDB_Federated_Server_List_Remote_Tables(server => 'loopback', remote_schema => 'remote_schema'); \echo '## Only the owner can revoke permissions over the server' SELECT cartodb.CDB_Federated_Server_Revoke_Access(server := 'loopback', db_role := 'cdb_fs_tester'::name); diff --git a/test/CDB_FederatedServerTables_expect b/test/CDB_FederatedServerTables_expect index 40ac9d8..8267a72 100644 --- a/test/CDB_FederatedServerTables_expect +++ b/test/CDB_FederatedServerTables_expect @@ -1,42 +1,37 @@ C1| ## Registering an existing table works R1| -V1| SELECT t.id AS cartodb_id, - t.geom AS the_geom, - st_transform(t.geom, 3857) AS the_geom_webmercator, - t.another_field - FROM cdb_fs_schema_b904664b5208433cd85a1693ba4f7570.remote_geom t; S1|1|POINT(1 1)|patata S1|2|POINT(2 2)|patata2 -list_remotes1|(remote_geom,public.remote_geom) +t|remote_geom|public.remote_geom|id|geom|geom|[{"Name" : "another_field", "Type" : "text"}, {"Name" : "geom", "Type" : "GEOMETRY,4326"}, {"Name" : "id", "Type" : "integer"}] +f|remote_geom2|||||[{"Name" : "another_field", "Type" : "text"}, {"Name" : "geom", "Type" : "GEOMETRY,4326"}, {"Name" : "geom_mercator", "Type" : "GEOMETRY,3857"}, {"Name" : "id", "Type" : "bigint"}] +f|remote_other|||||[{"Name" : "field", "Type" : "text"}, {"Name" : "field2", "Type" : "text"}, {"Name" : "id", "Type" : "bigint"}] ## Registering another existing table works R2| -V2| SELECT t.id AS cartodb_id, - t.geom AS the_geom, - t.geom_mercator AS the_geom_webmercator, - t.another_field - FROM cdb_fs_schema_b904664b5208433cd85a1693ba4f7570.remote_geom2 t; S2|3|POINT(3 3)|patata -list_remotes2|(remote_geom2,"public.""myFullTable""") -list_remotes2|(remote_geom,public.remote_geom) +t|remote_geom|public.remote_geom|id|geom|geom|[{"Name" : "another_field", "Type" : "text"}, {"Name" : "geom", "Type" : "GEOMETRY,4326"}, {"Name" : "id", "Type" : "integer"}] +t|remote_geom2|public."myFullTable"|id|geom|geom_mercator|[{"Name" : "another_field", "Type" : "text"}, {"Name" : "geom", "Type" : "GEOMETRY,4326"}, {"Name" : "geom_mercator", "Type" : "GEOMETRY,3857"}, {"Name" : "id", "Type" : "bigint"}] +f|remote_other|||||[{"Name" : "field", "Type" : "text"}, {"Name" : "field2", "Type" : "text"}, {"Name" : "id", "Type" : "bigint"}] ## Re-registering a table works R3| -ERROR: relation "myFullTable" does not exist at character 70 -S3_new|3|POINT(3 3)|patata +ERROR: relation "myFullTable" does not exist at character 49 +S3_new|3|patata ## Unregistering works U1| ERROR: relation "remote_geom" does not exist at character 71 -list_remotes3|(remote_geom2,public.different_name) +f|remote_geom|||||[{"Name" : "another_field", "Type" : "text"}, {"Name" : "geom", "Type" : "GEOMETRY,4326"}, {"Name" : "id", "Type" : "integer"}] +t|remote_geom2|public.different_name|id|geom_mercator|geom|[{"Name" : "another_field", "Type" : "text"}, {"Name" : "geom", "Type" : "GEOMETRY,4326"}, {"Name" : "geom_mercator", "Type" : "GEOMETRY,3857"}, {"Name" : "id", "Type" : "bigint"}] +f|remote_other|||||[{"Name" : "field", "Type" : "text"}, {"Name" : "field2", "Type" : "text"}, {"Name" : "id", "Type" : "bigint"}] ## Registering a table: Invalid server fails ERROR: Server "Does not exist" does not exist ## Registering a table: NULL server fails ERROR: Server name cannot be NULL ## Registering a table: Invalid schema fails -ERROR: schema "Does not exist" is not present on foreign server "cdb_fs_loopback" +ERROR: Could not import schema "Does not exist" of server "loopback" ## Registering a table: NULL schema fails ERROR: Schema name cannot be NULL ## Registering a table: Invalid table fails -ERROR: relation "cdb_fs_schema_b904664b5208433cd85a1693ba4f7570.Does not exist" does not exist +ERROR: Could not import table "remote_schema.Does not exist" of server "loopback" ## Registering a table: NULL table fails ERROR: Remote table name cannot be NULL ## Registering a table: Invalid id fails @@ -64,16 +59,17 @@ DROP TABLE ## Registering tables does not work without permissions You are now connected to database "contrib_regression" as user "cdb_fs_tester". ERROR: Not enough permissions to access the server "loopback" -## Listing registered tables does not work without permissions +## Listing remote tables does not work without permissions ERROR: Not enough permissions to access the server "loopback" ## Registering tables works with granted permissions You are now connected to database "contrib_regression" as user "postgres". You are now connected to database "contrib_regression" as user "cdb_fs_tester". -## Listing registered tables works with granted permissions -(remote_geom2,public.different_name) -(remote_geom,public.localtable) +## Listing remote tables works with granted permissions +t|remote_geom|public.localtable|id|geom|geom|[{"Name" : "another_field", "Type" : "text"}, {"Name" : "geom", "Type" : "GEOMETRY,4326"}, {"Name" : "id", "Type" : "integer"}] +t|remote_geom2|public.different_name|id|geom_mercator|geom|[{"Name" : "another_field", "Type" : "text"}, {"Name" : "geom", "Type" : "GEOMETRY,4326"}, {"Name" : "geom_mercator", "Type" : "GEOMETRY,3857"}, {"Name" : "id", "Type" : "bigint"}] +f|remote_other|||||[{"Name" : "field", "Type" : "text"}, {"Name" : "field2", "Type" : "text"}, {"Name" : "id", "Type" : "bigint"}] ## Selecting from a registered table with granted permissions works 1|POINT(1 1) 2|POINT(2 2) @@ -90,14 +86,17 @@ ERROR: You do not have rights to grant access on "loopback" You are now connected to database "contrib_regression" as user "postgres". You are now connected to database "contrib_regression" as user "cdb_fs_tester2". -(remote_geom2,public.different_name) -(remote_geom,public.localtable) +t|remote_geom|public.localtable|id|geom|geom|[{"Name" : "another_field", "Type" : "text"}, {"Name" : "geom", "Type" : "GEOMETRY,4326"}, {"Name" : "id", "Type" : "integer"}] +t|remote_geom2|public.different_name|id|geom_mercator|geom|[{"Name" : "another_field", "Type" : "text"}, {"Name" : "geom", "Type" : "GEOMETRY,4326"}, {"Name" : "geom_mercator", "Type" : "GEOMETRY,3857"}, {"Name" : "id", "Type" : "bigint"}] +f|remote_other|||||[{"Name" : "field", "Type" : "text"}, {"Name" : "field2", "Type" : "text"}, {"Name" : "id", "Type" : "bigint"}] 1|POINT(1 1) 2|POINT(2 2) ## A different user can unregister a table NOTICE: drop cascades to view localtable -(remote_geom2,public.different_name) +f|remote_geom|||||[{"Name" : "another_field", "Type" : "text"}, {"Name" : "geom", "Type" : "GEOMETRY,4326"}, {"Name" : "id", "Type" : "integer"}] +t|remote_geom2|public.different_name|id|geom_mercator|geom|[{"Name" : "another_field", "Type" : "text"}, {"Name" : "geom", "Type" : "GEOMETRY,4326"}, {"Name" : "geom_mercator", "Type" : "GEOMETRY,3857"}, {"Name" : "id", "Type" : "bigint"}] +f|remote_other|||||[{"Name" : "field", "Type" : "text"}, {"Name" : "field2", "Type" : "text"}, {"Name" : "id", "Type" : "bigint"}] ## Only the owner can revoke permissions over the server ERROR: You do not have rights to revoke access on "loopback" D1|