Compare commits

...

28 Commits

Author SHA1 Message Date
Rafa de la Torre
ebeea3605e Fix typo in exception
Sorry, the shell testing framework doesn't make it easy to test it,
@Algunenano
2019-10-15 17:33:00 +02:00
Rafa de la Torre
10997d5e29 Avoid clashing of carto column names 2019-10-15 16:21:35 +02:00
Rafa de la Torre
b82025a866 Add another test case for clashing column names 2019-10-15 16:20:55 +02:00
Rafa de la Torre
e5b1345311 Avoid name clashing no geom columns provided but existing the_geom
Fix for CDB_SetUp_PG_Federated_Table('server', 'schema', 'table', 'id)
when the table contains the_geom and/or the_geom_webmercator columns
but they are not part of the input.

Otherwise it fails with

    ERROR:  column "the_geom" specified more than once
2019-10-15 16:01:16 +02:00
Rafa de la Torre
e0e15a9886 Fix for __ft_assert_numeric doesn't exists 2019-10-15 13:19:09 +02:00
Rafa de la Torre
77581ca140 Change type of server_alias from text to name
On the one hand this is done for consistency with the rest of
parameters.

On the other hand this is the "correct" type, as it is more
restrictive than `text` type (`name` is limited to 64 bytes and the
generated object names will use that type and suffer the same length
limitation) and it is more suitable to build db object names.
2019-10-14 15:52:59 +02:00
Rafa de la Torre
fef2f05255 Schema-qualify Find_SRID 2019-10-14 15:52:59 +02:00
Rafa de la Torre
568d7d12be Fully qualify all-the-things
Add the schema qualifier to all function calls in postgis and cartodb
extensions.
2019-10-14 15:52:59 +02:00
Rafa de la Torre
8068250b49 Change private asserts to checks
As per review suggestion, change asserts to return bools instead of
raising exception and let the caller decide what to do.
2019-10-14 15:52:59 +02:00
Rafa de la Torre
31ef9d54f2 Rename function for clarity
__ft_add_default_options renamed to __ft_add_default_readonly_options
to state clearly it is for the read only configuration.
2019-10-14 15:52:59 +02:00
Rafa de la Torre
5a33e0bc02 Improve and add a couple more tests 2019-10-14 15:52:59 +02:00
Rafa de la Torre
595ed219b9 Remove a bit of noise from tests
s/ --.*//
s/carto_remote_table/remote_table/
2019-10-14 15:52:59 +02:00
Rafa de la Torre
c389eb9120 Fix exceptions
They were instead raising `column "id_column" does not exist`
2019-10-14 15:52:59 +02:00
Rafa de la Torre
8e1b659caf Add missing functions to make geom and webmercator params optional 2019-10-14 15:52:59 +02:00
Rafa de la Torre
1b815d0674 Improve function inline doc 2019-10-14 15:52:59 +02:00
Rafa de la Torre
c2ed259a2c Add the ST_Transform only when needed 2019-10-14 15:52:59 +02:00
Rafa de la Torre
2288629765 Generate view mapping columns to CDB names 2019-10-14 15:52:59 +02:00
Rafa de la Torre
4c7d6c4564 Add a couple function asserts 2019-10-14 15:52:59 +02:00
Rafa de la Torre
4861a21e81 Check for numeric id column 2019-10-14 15:52:59 +02:00
Rafa de la Torre
42a16070c9 Marginally improve test case data 2019-10-14 15:52:59 +02:00
Rafa de la Torre
2b1046dec3 Basic implementation of CDB_SetUp_PG_Federated_Table (WIP) 2019-10-14 15:52:59 +02:00
Rafa de la Torre
2b0aca2d08 Rename private functions
Rename __cdb_* "private" functions to __ft_*, kind of a namespace to
avoid name clashing.
2019-10-14 15:52:59 +02:00
Rafa de la Torre
32eae57551 __cdb_add_default_options function and tests 2019-10-14 15:52:59 +02:00
Rafa de la Torre
45f60e06b7 __cdb_credentials_to_user_mapping function & test 2019-10-14 15:52:59 +02:00
Rafa de la Torre
46347249cb Minimal implementation 2019-10-14 15:52:59 +02:00
Rafa de la Torre
e24c550195 Simplify setup and teardown of fdw_target 2019-10-14 15:52:59 +02:00
Rafa de la Torre
1a587c3101 Extract setup and teardown of fdw_target 2019-10-14 15:52:59 +02:00
Rafa de la Torre
8e005e556e Skeleton for CDB_SetUp_PG_Federated_Server 2019-10-14 15:52:59 +02:00
3 changed files with 527 additions and 25 deletions

View File

@ -0,0 +1,299 @@
----------------------------------------------------------------------
-- 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_readonly_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@.__ft_is_numeric(input_table regclass, colname name)
RETURNS boolean
AS $$
BEGIN
PERFORM atttypid FROM pg_catalog.pg_attribute
WHERE attrelid = input_table
AND attname = colname
AND atttypid IN (SELECT oid FROM pg_type
WHERE typname IN
('smallint', 'integer', 'bigint', 'int2', 'int4', 'int8'));
RETURN FOUND;
END
$$
LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE;
CREATE OR REPLACE FUNCTION @extschema@.__ft_is_geometry(input_table regclass, colname name)
RETURNS boolean
AS $$
BEGIN
PERFORM atttypid FROM pg_catalog.pg_attribute
WHERE attrelid = input_table
AND attname = colname
AND atttypid = 'geometry'::regtype;
RETURN FOUND;
END
$$
LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE;
CREATE OR REPLACE FUNCTION @extschema@.__ft_getcolumns(input_table REGCLASS)
RETURNS SETOF NAME
AS $$
SELECT
a.attname as "colname"
FROM
pg_catalog.pg_attribute a
WHERE
a.attnum > 0
AND NOT a.attisdropped
AND a.attrelid = (
SELECT c.oid
FROM pg_catalog.pg_class c
LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
WHERE c.oid = input_table::oid
)
ORDER BY a.attnum;
$$ LANGUAGE SQL;
--------------------------------------------------------------------------------
-- Public functions
--------------------------------------------------------------------------------
--
-- 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 name, server_config jsonb)
RETURNS void
AS $$
DECLARE
final_config jsonb;
BEGIN
final_config := @extschema@.__ft_credentials_to_user_mapping(
@extschema@.__ft_add_default_readonly_options(server_config)
);
PERFORM @extschema@._CDB_SetUp_User_PG_FDW_Server(server_alias, final_config::json);
END
$$
LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE;
--
-- Set up a Federated Table
--
-- Precondition: the federated server has to be set up via
-- CDB_SetUp_PG_Federated_Server
--
-- Postcondition: it generates a view in the schema of the user that
-- can be used through SQL and Maps API's.
--
-- E.g:
-- SELECT cartodb.CDB_SetUp_PG_Federated_Table(
-- 'amazon', -- mandatory, name of the federated server
-- 'my_remote_schema', -- mandatory, schema name
-- 'my_remote_table', -- mandatory, table name
-- 'id', -- mandatory, name of the id column
-- 'geom', -- optional, name of the geom column, preferably in 4326
-- 'webmercator' -- optional, should be in 3857 if present
-- );
--
CREATE OR REPLACE FUNCTION @extschema@.CDB_SetUp_PG_Federated_Table(
server_alias name,
schema_name name,
table_name name,
id_column name,
geom_column name,
webmercator_column name
)
RETURNS void
AS $$
DECLARE
fdw_objects_name NAME := @extschema@.__CDB_User_FDW_Object_Names(server_alias);
src_table REGCLASS;
rest_of_cols TEXT[];
geom_expression TEXT;
webmercator_expression TEXT;
BEGIN
-- Import the foreign table
PERFORM @extschema@.CDB_SetUp_User_PG_FDW_Table(server_alias, schema_name, table_name);
src_table := format('%s.%s', fdw_objects_name, table_name);
-- Check id_column is numeric
IF NOT @extschema@.__ft_is_numeric(src_table, id_column) THEN
RAISE EXCEPTION 'non integer id_column "%"', id_column;
END IF;
-- Check if the geom and mercator columns have a geometry type
IF NOT @extschema@.__ft_is_geometry(src_table, geom_column) THEN
RAISE EXCEPTION 'non geometry column "%"', geom_column;
END IF;
IF NOT @extschema@.__ft_is_geometry(src_table, webmercator_column) THEN
RAISE EXCEPTION 'non geometry column "%"', webmercator_column;
END IF;
-- Get a list of columns excluding the id, geom and the_geom_webmercator
SELECT ARRAY(
SELECT quote_ident(c) FROM @extschema@.__ft_getcolumns(src_table) AS c
WHERE c NOT IN (id_column, geom_column, webmercator_column, 'cartodb_id', 'the_geom', 'the_geom_webmercator')
) INTO rest_of_cols;
-- Figure out whether a ST_Transform to 4326 is needed or not
IF @postgisschema@.Find_SRID(fdw_objects_name::varchar, table_name::varchar, geom_column::varchar) = 4326
THEN
geom_expression := format('t.%I AS the_geom', geom_column);
ELSE
geom_expression := format('@postgisschema@.ST_Transform(t.%I, 4326) AS the_geom', geom_column);
END IF;
-- Figure out whether a ST_Transform to 3857 is needed or not
IF Find_SRID(fdw_objects_name::varchar, table_name::varchar, webmercator_column::varchar) = 3857
THEN
webmercator_expression := format('t.%I AS the_geom_webmercator', webmercator_column);
ELSE
webmercator_expression := format('@postgisschema@.ST_Transform(t.%I, 3857) AS the_geom_webmercator', webmercator_column);
END IF;
-- Create a view with homogeneous CDB fields
EXECUTE format(
'CREATE OR REPLACE VIEW %1$I AS
SELECT
t.%2$I AS cartodb_id,
%3$s,
%4$s,
%5$s
FROM %6$s t',
table_name,
id_column,
geom_expression,
webmercator_expression,
array_to_string(rest_of_cols, ','),
src_table
);
-- Grant perms to the view
EXECUTE format('GRANT SELECT ON %I TO %s', table_name, fdw_objects_name);
END
$$
LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE;
CREATE OR REPLACE FUNCTION @extschema@.CDB_SetUp_PG_Federated_Table(
server_alias name,
schema_name name,
table_name name,
id_column name,
geom_column name
)
RETURNS void
AS $$
SELECT @extschema@.CDB_SetUp_PG_Federated_Table(
server_alias,
schema_name,
table_name,
id_column,
geom_column,
geom_column
);
$$
LANGUAGE SQL VOLATILE PARALLEL UNSAFE;
CREATE OR REPLACE FUNCTION @extschema@.CDB_SetUp_PG_Federated_Table(
server_alias name,
schema_name name,
table_name name,
id_column name
)
RETURNS void
AS $$
DECLARE
fdw_objects_name NAME := @extschema@.__CDB_User_FDW_Object_Names(server_alias);
src_table REGCLASS;
rest_of_cols TEXT[];
BEGIN
-- Import the foreign table
PERFORM @extschema@.CDB_SetUp_User_PG_FDW_Table(server_alias, schema_name, table_name);
src_table := format('%s.%s', fdw_objects_name, table_name);
-- Check id_column is numeric
IF NOT @extschema@.__ft_is_numeric(src_table, id_column) THEN
RAISE EXCEPTION 'non integer id_column "%"', id_column;
END IF;
-- Get a list of columns excluding the id
SELECT ARRAY(
SELECT quote_ident(c) FROM @extschema@.__ft_getcolumns(src_table) AS c
WHERE c NOT IN (id_column, 'cartodb_id', 'the_geom', 'the_geom_webmercator')
) INTO rest_of_cols;
-- Create a view with homogeneous CDB fields
EXECUTE format(
'CREATE OR REPLACE VIEW %1$I AS
SELECT
t.%2$I AS cartodb_id,
NULL AS the_geom,
NULL AS the_geom_webmercator,
%3$s
FROM %4$s t',
table_name,
id_column,
array_to_string(rest_of_cols, ','),
src_table
);
-- Grant perms to the view
EXECUTE format('GRANT SELECT ON %I TO %s', table_name, fdw_objects_name);
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,37 @@ 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);"
sql postgres "SELECT cartodb.CDB_SetUserQuotaInBytes('test_fdw', 0);"
}
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,18 +670,201 @@ 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)"
# Teardown
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
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_readonly_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_readonly_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}'
# It shall be able to register a fully cartodbfied table
DATABASE=fdw_target sql postgres 'CREATE TABLE test_fdw.remote_table (cartodb_id int, another_field text, geom geometry(Geometry,4326));'
DATABASE=fdw_target sql postgres "INSERT INTO test_fdw.remote_table VALUES (1, 'patata', cartodb.CDB_LatLng(0, 0));"
DATABASE=fdw_target sql postgres "SELECT cartodb.CDB_CartodbfyTable('test_fdw', 'test_fdw.remote_table');"
DATABASE=fdw_target sql postgres 'GRANT SELECT ON TABLE test_fdw.remote_table TO fdw_user;'
sql cdb_testmember_1 "SELECT cartodb.CDB_SetUp_PG_Federated_Table(
'my_server',
'test_fdw',
'remote_table',
'cartodb_id',
'the_geom',
'the_geom_webmercator'
)"
# Now it shall be able to access the table/view from its schema
# the resulting table should have CDB form
sql cdb_testmember_1 "SELECT cartodb_id, the_geom, the_geom_webmercator FROM remote_table;"
sql cdb_testmember_1 "SELECT cartodb_id, ST_AsText(the_geom) FROM remote_table;" should '1|POINT(0 0)'
# In this sunnyday case, it does not need to generate ST_Transforms
sql cdb_testmember_1 "SELECT pg_get_viewdef('remote_table')" should ' SELECT t.cartodb_id,
t.the_geom,
t.the_geom_webmercator,
t.another_field
FROM cdb_fdw_my_server.remote_table t;'
# It fails if the id column is not numeric
DATABASE=fdw_target sql postgres 'CREATE TABLE test_fdw.remote_table2 (cartodb_id text, geom geometry(Geometry,4326));'
DATABASE=fdw_target sql postgres 'GRANT SELECT ON TABLE test_fdw.remote_table2 TO fdw_user;'
sql cdb_testmember_1 "SELECT cartodb.CDB_SetUp_PG_Federated_Table(
'my_server',
'test_fdw',
'remote_table2',
'another_field',
'the_geom',
'the_geom_webmercator'
)" fails
# It fails if the provided geom column is not of geometry type
DATABASE=fdw_target sql postgres 'CREATE TABLE test_fdw.remote_table3 (cartodb_id int, geom varchar);'
DATABASE=fdw_target sql postgres 'GRANT SELECT ON TABLE test_fdw.remote_table3 TO fdw_user;'
sql cdb_testmember_1 "SELECT cartodb.CDB_SetUp_PG_Federated_Table(
'my_server',
'test_fdw',
'remote_table3',
'cartodb_id',
'the_geom',
'the_geom_webmercator'
)" fails
# It does a correct mapping of fields when source is not in CDB form
DATABASE=fdw_target sql postgres 'CREATE TABLE test_fdw.remote_table4 (id int, another_field text, geom geometry(Geometry,4326));'
DATABASE=fdw_target sql postgres "INSERT INTO test_fdw.remote_table4 VALUES (1, 'patata', cartodb.CDB_LatLng(0, 0));"
sql cdb_testmember_1 "SELECT cartodb.CDB_SetUp_PG_Federated_Table(
'my_server',
'test_fdw',
'remote_table4',
'id',
'geom'
)"
sql cdb_testmember_1 "SELECT cartodb_id, ST_AsText(the_geom) FROM remote_table;" should '1|POINT(0 0)'
sql cdb_testmember_1 "SELECT pg_get_viewdef('remote_table4')" should ' 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_fdw_my_server.remote_table4 t;'
# It shall work without any geometries
DATABASE=fdw_target sql postgres 'CREATE TABLE test_fdw.remote_table5 (id int, another_field text);'
DATABASE=fdw_target sql postgres 'GRANT SELECT ON TABLE test_fdw.remote_table5 TO fdw_user;'
DATABASE=fdw_target sql postgres "INSERT INTO test_fdw.remote_table5 VALUES (1, 'patata');"
sql cdb_testmember_1 "SELECT cartodb.CDB_SetUp_PG_Federated_Table(
'my_server',
'test_fdw',
'remote_table5',
'id'
)"
sql cdb_testmember_1 "SELECT cartodb_id, another_field, the_geom, the_geom_webmercator FROM remote_table5;" should '1|patata||'
# It shall work without any geometries, even if the table has the_geom or the_geom_webmercator
DATABASE=fdw_target sql postgres 'CREATE TABLE test_fdw.remote_table6 (id int, another_field text, the_geom geometry(Geometry,4326), the_geom_webmercator geometry(Geometry,3857));'
DATABASE=fdw_target sql postgres 'GRANT SELECT ON TABLE test_fdw.remote_table6 TO fdw_user;'
DATABASE=fdw_target sql postgres "INSERT INTO test_fdw.remote_table6 VALUES (1, 'patata', cartodb.CDB_latLng(0,0), ST_Transform(cartodb.CDB_LatLng(0, 0), 3857));"
sql cdb_testmember_1 "SELECT cartodb.CDB_SetUp_PG_Federated_Table(
'my_server',
'test_fdw',
'remote_table6',
'id'
)"
sql cdb_testmember_1 "SELECT cartodb_id, another_field, the_geom, the_geom_webmercator FROM remote_table6;" should '1|patata||'
# similar case, when providing a geom column, with potential clashing of the_geom_webmercator
sql cdb_testmember_1 "DROP VIEW remote_table6;"
sql cdb_testmember_1 "DROP FOREIGN TABLE cdb_fdw_my_server.remote_table6;"
sql cdb_testmember_1 "SELECT cartodb.CDB_SetUp_PG_Federated_Table(
'my_server',
'test_fdw',
'remote_table6',
'id',
'the_geom'
)"
sql cdb_testmember_1 "SELECT cartodb_id, another_field, ST_AsText(the_geom) FROM remote_table6;" should '1|patata|POINT(0 0)'
# Tear down
DATABASE=fdw_target sql postgres 'REVOKE ALL ON ALL TABLES IN SCHEMA test_fdw FROM fdw_user;'
sql postgres "SELECT cartodb._CDB_Drop_User_PG_FDW_Server('my_server', /* force = */ true)"
tear_down_fdw_target
}
function test_cdb_catalog_basic_node() {
DEF="'{\"type\":\"buffer\",\"source\":\"b2db66bc7ac02e135fd20bbfef0fdd81b2d15fad\",\"radio\":10000}'"
sql postgres "INSERT INTO cartodb.cdb_analysis_catalog (node_id, analysis_def) VALUES ('1bbc4c41ea7c9d3a7dc1509727f698b7', ${DEF}::json)"