From 7b52058265daab483e0db54467bff739e37fd6d0 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Alejandro=20Mart=C3=ADnez?= Date: Wed, 3 Feb 2016 17:50:13 +0100 Subject: [PATCH 01/31] Add CDB_ForeignTable functions --- scripts-available/CDB_ForeignTable.sql | 108 +++++++++++++++++++++++ scripts-enabled/250-CDB_ForeignTable.sql | 1 + 2 files changed, 109 insertions(+) create mode 100644 scripts-available/CDB_ForeignTable.sql create mode 120000 scripts-enabled/250-CDB_ForeignTable.sql diff --git a/scripts-available/CDB_ForeignTable.sql b/scripts-available/CDB_ForeignTable.sql new file mode 100644 index 0000000..476851b --- /dev/null +++ b/scripts-available/CDB_ForeignTable.sql @@ -0,0 +1,108 @@ +--------------------------- +-- FDW MANAGEMENT FUNCTIONS +-- +-- All the FDW settings are read from the `cdb_conf.fdws` entry json file. +--------------------------- + +CREATE OR REPLACE FUNCTION cartodb._CDB_Create_FDW(name text, config json) +RETURNS void +AS $$ +DECLARE + row record; + option record; + org_role text; +BEGIN + IF NOT EXISTS ( SELECT * FROM pg_extension WHERE extname = 'postgres_fdw') + THEN + CREATE EXTENSION postgres_fdw; + END IF; + -- This function is idempotent + -- Create FDW first if it does not exist + IF NOT EXISTS ( SELECT * FROM pg_foreign_server WHERE srvname = name) + THEN + EXECUTE FORMAT('CREATE SERVER %I FOREIGN DATA WRAPPER postgres_fdw ', + name); + END IF; + + -- Set FDW settings + FOR row IN SELECT p.key, p.value from lateral json_each_text(config->'server') p + LOOP + IF NOT EXISTS (WITH a AS (select split_part(unnest(srvoptions), '=', 1) as options from pg_foreign_server where srvname=name) SELECT * from a where options = row.key) + THEN + EXECUTE FORMAT('ALTER SERVER %I OPTIONS (ADD %I %L)', name, row.key, row.value); + ELSE + EXECUTE FORMAT('ALTER SERVER %I OPTIONS (SET %I %L)', name, row.key, row.value); + END IF; + END LOOP; + + -- Create user mappings + FOR row IN SELECT p.key, p.value from lateral json_each(config->'users') p + LOOP + -- Check if entry on pg_user_mappings exists + + IF NOT EXISTS ( SELECT * FROM pg_user_mappings WHERE srvname = name AND usename = row.key ) + THEN + EXECUTE FORMAT ('CREATE USER MAPPING FOR %I SERVER %I', row.key, name); + END IF; + + -- Update user mapping settings + FOR option IN SELECT o.key, o.value from lateral json_each_text(row.value) o + LOOP + IF NOT EXISTS (WITH a AS (select split_part(unnest(umoptions), '=', 1) as options from pg_user_mappings WHERE srvname = name AND usename = row.key) SELECT * from a where options = option.key) + THEN + EXECUTE FORMAT('ALTER USER MAPPING FOR %I SERVER %I OPTIONS (ADD %I %L)', row.key, name, option.key, option.value); + ELSE + EXECUTE FORMAT('ALTER USER MAPPING FOR %I SERVER %I OPTIONS (SET %I %L)', row.key, name, option.key, option.value); + END IF; + END LOOP; + END LOOP; + + -- Create schema if it does not exist. + IF NOT EXISTS ( SELECT * from pg_namespace WHERE nspname=name) + THEN + EXECUTE FORMAT ('CREATE SCHEMA %I', name); + END IF; + + -- Give the organization role usage permisions over the schema + SELECT cartodb.CDB_Organization_Member_Group_Role_Member_Name() INTO org_role; + EXECUTE FORMAT ('GRANT USAGE ON SCHEMA %I TO %I', name, org_role); + + -- Bring here the remote cdb_tablemetadata + IF NOT EXISTS ( SELECT * FROM PG_CLASS WHERE relnamespace = (SELECT oid FROM pg_namespace WHERE nspname='do') and relname='cdb_tablemetadata') + THEN + EXECUTE FORMAT ('IMPORT FOREIGN SCHEMA cartodb LIMIT TO (cdb_tablemetadata) FROM SERVER %I INTO %I;', name, name, name); + END IF; + EXECUTE FORMAT ('GRANT SELECT ON %I.cdb_tablemetadata TO %I', name, org_role); + +END +$$ +LANGUAGE PLPGSQL; + +CREATE OR REPLACE FUNCTION cartodb._CDB_Create_FDWS() +RETURNS VOID AS +$$ +DECLARE +row record; +BEGIN + FOR row IN SELECT p.key, p.value from lateral json_each(cartodb.CDB_Conf_GetConf('fdws')) p + LOOP + EXECUTE 'SELECT cartodb._CDB_Create_FDW($1, $2)' USING row.key, row.value; + END LOOP; + END + $$ + LANGUAGE PLPGSQL; + +CREATE OR REPLACE FUNCTION cartodb.CDB_Add_Remote_Table(source text, table_name text) +RETURNS void AS +$$ +BEGIN +PERFORM cartodb._CDB_Create_FDW(source); +EXECUTE FORMAT ('IMPORT FOREIGN SCHEMA %I LIMIT TO (%I) FROM SERVER %I INTO %I;', source, table_name, source, source); +--- Grant SELECT to publicuser +EXECUTE FORMAT ('GRANT SELECT ON %I.%I TO publicuser;', source, table_name); + +END +$$ +LANGUAGE plpgsql +security definer; + diff --git a/scripts-enabled/250-CDB_ForeignTable.sql b/scripts-enabled/250-CDB_ForeignTable.sql new file mode 120000 index 0000000..4154d35 --- /dev/null +++ b/scripts-enabled/250-CDB_ForeignTable.sql @@ -0,0 +1 @@ +../scripts-available/CDB_ForeignTable.sql \ No newline at end of file From d7b560324a85137eb74675057eadd36f5c7f7b89 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Alejandro=20Mart=C3=ADnez?= Date: Wed, 3 Feb 2016 18:07:23 +0100 Subject: [PATCH 02/31] Add _Create_FDW function to create a FDW defined on the config by name --- scripts-available/CDB_ForeignTable.sql | 14 ++++++++++++++ 1 file changed, 14 insertions(+) diff --git a/scripts-available/CDB_ForeignTable.sql b/scripts-available/CDB_ForeignTable.sql index 476851b..2c88336 100644 --- a/scripts-available/CDB_ForeignTable.sql +++ b/scripts-available/CDB_ForeignTable.sql @@ -92,6 +92,20 @@ BEGIN $$ LANGUAGE PLPGSQL; + +CREATE OR REPLACE FUNCTION cartodb._CDB_Create_FDW(name text) + RETURNS void AS +$BODY$ +DECLARE +config json; +BEGIN + SELECT p.value FROM LATERAL json_each(cartodb.CDB_Conf_GetConf('fdws')) p WHERE p.key = name INTO config; + EXECUTE 'SELECT cartodb._CDB_Create_FDW($1, $2)' USING name, config; +END +$BODY$ +LANGUAGE plpgsql VOLATILE +SECURITY DEFINER; + CREATE OR REPLACE FUNCTION cartodb.CDB_Add_Remote_Table(source text, table_name text) RETURNS void AS $$ From a9b9f1ff6cd3a51af89cde853cf49bcd527be4ac Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Alejandro=20Mart=C3=ADnez?= Date: Thu, 4 Feb 2016 12:06:22 +0100 Subject: [PATCH 03/31] Rename CDB_FDW_Create to CDB_FDW_Setup, formatting fixes --- scripts-available/CDB_ForeignTable.sql | 84 +++++++++++--------------- 1 file changed, 36 insertions(+), 48 deletions(-) diff --git a/scripts-available/CDB_ForeignTable.sql b/scripts-available/CDB_ForeignTable.sql index 2c88336..9e94729 100644 --- a/scripts-available/CDB_ForeignTable.sql +++ b/scripts-available/CDB_ForeignTable.sql @@ -4,7 +4,7 @@ -- All the FDW settings are read from the `cdb_conf.fdws` entry json file. --------------------------- -CREATE OR REPLACE FUNCTION cartodb._CDB_Create_FDW(name text, config json) +CREATE OR REPLACE FUNCTION cartodb._CDB_Setup_FDW(fdw_name text, config json) RETURNS void AS $$ DECLARE @@ -12,55 +12,49 @@ DECLARE option record; org_role text; BEGIN - IF NOT EXISTS ( SELECT * FROM pg_extension WHERE extname = 'postgres_fdw') - THEN + -- 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; END IF; - -- This function is idempotent -- Create FDW first if it does not exist - IF NOT EXISTS ( SELECT * FROM pg_foreign_server WHERE srvname = name) + IF NOT EXISTS ( SELECT * FROM pg_foreign_server WHERE srvname = fdw_name) THEN - EXECUTE FORMAT('CREATE SERVER %I FOREIGN DATA WRAPPER postgres_fdw ', - name); + EXECUTE FORMAT('CREATE SERVER %I FOREIGN DATA WRAPPER postgres_fdw', fdw_name); END IF; -- Set FDW settings FOR row IN SELECT p.key, p.value from lateral json_each_text(config->'server') p LOOP - IF NOT EXISTS (WITH a AS (select split_part(unnest(srvoptions), '=', 1) as options from pg_foreign_server where srvname=name) SELECT * from a where options = row.key) + IF NOT EXISTS (WITH a AS (select split_part(unnest(srvoptions), '=', 1) as options from pg_foreign_server where srvname=fdw_name) SELECT * from a where options = row.key) THEN - EXECUTE FORMAT('ALTER SERVER %I OPTIONS (ADD %I %L)', name, row.key, row.value); + EXECUTE FORMAT('ALTER SERVER %I OPTIONS (ADD %I %L)', fdw_name, row.key, row.value); ELSE - EXECUTE FORMAT('ALTER SERVER %I OPTIONS (SET %I %L)', name, row.key, row.value); + EXECUTE FORMAT('ALTER SERVER %I OPTIONS (SET %I %L)', fdw_name, row.key, row.value); END IF; END LOOP; -- Create user mappings - FOR row IN SELECT p.key, p.value from lateral json_each(config->'users') p - LOOP + FOR row IN SELECT p.key, p.value from lateral json_each(config->'users') p LOOP -- Check if entry on pg_user_mappings exists - IF NOT EXISTS ( SELECT * FROM pg_user_mappings WHERE srvname = name AND usename = row.key ) - THEN - EXECUTE FORMAT ('CREATE USER MAPPING FOR %I SERVER %I', row.key, name); + IF NOT EXISTS ( SELECT * FROM pg_user_mappings WHERE srvname = name AND usename = row.key ) THEN + EXECUTE FORMAT ('CREATE USER MAPPING FOR %I SERVER %I', row.key, fdw_name); END IF; -- Update user mapping settings - FOR option IN SELECT o.key, o.value from lateral json_each_text(row.value) o - LOOP - IF NOT EXISTS (WITH a AS (select split_part(unnest(umoptions), '=', 1) as options from pg_user_mappings WHERE srvname = name AND usename = row.key) SELECT * from a where options = option.key) - THEN - EXECUTE FORMAT('ALTER USER MAPPING FOR %I SERVER %I OPTIONS (ADD %I %L)', row.key, name, option.key, option.value); + FOR option IN SELECT o.key, o.value from lateral json_each_text(row.value) o LOOP + IF NOT EXISTS (WITH a AS (select split_part(unnest(umoptions), '=', 1) as options from pg_user_mappings WHERE srvname = name AND usename = row.key) SELECT * from a where options = option.key) THEN + EXECUTE FORMAT('ALTER USER MAPPING FOR %I SERVER %I OPTIONS (ADD %I %L)', row.key, fdw_name, option.key, option.value); ELSE - EXECUTE FORMAT('ALTER USER MAPPING FOR %I SERVER %I OPTIONS (SET %I %L)', row.key, name, option.key, option.value); + EXECUTE FORMAT('ALTER USER MAPPING FOR %I SERVER %I OPTIONS (SET %I %L)', row.key, fdw_name, option.key, option.value); END IF; END LOOP; END LOOP; -- Create schema if it does not exist. - IF NOT EXISTS ( SELECT * from pg_namespace WHERE nspname=name) - THEN - EXECUTE FORMAT ('CREATE SCHEMA %I', name); + IF NOT EXISTS ( SELECT * from pg_namespace WHERE nspname=fdw_name) THEN + EXECUTE FORMAT ('CREATE SCHEMA %I', fdw_name); END IF; -- Give the organization role usage permisions over the schema @@ -68,55 +62,49 @@ BEGIN EXECUTE FORMAT ('GRANT USAGE ON SCHEMA %I TO %I', name, org_role); -- Bring here the remote cdb_tablemetadata - IF NOT EXISTS ( SELECT * FROM PG_CLASS WHERE relnamespace = (SELECT oid FROM pg_namespace WHERE nspname='do') and relname='cdb_tablemetadata') - THEN - EXECUTE FORMAT ('IMPORT FOREIGN SCHEMA cartodb LIMIT TO (cdb_tablemetadata) FROM SERVER %I INTO %I;', name, name, name); + IF NOT EXISTS ( SELECT * FROM PG_CLASS WHERE relnamespace = (SELECT oid FROM pg_namespace WHERE nspname='do') and relname='cdb_tablemetadata') THEN + EXECUTE FORMAT ('IMPORT FOREIGN SCHEMA cartodb LIMIT TO (cdb_tablemetadata) FROM SERVER %I INTO %I;', fdw_name, fdw_name, fdw_name); END IF; - EXECUTE FORMAT ('GRANT SELECT ON %I.cdb_tablemetadata TO %I', name, org_role); + EXECUTE FORMAT ('GRANT SELECT ON %I.cdb_tablemetadata TO %I', fdw_name, org_role); END $$ LANGUAGE PLPGSQL; -CREATE OR REPLACE FUNCTION cartodb._CDB_Create_FDWS() +CREATE OR REPLACE FUNCTION cartodb._CDB_Setup_FDWS() RETURNS VOID AS $$ DECLARE row record; BEGIN - FOR row IN SELECT p.key, p.value from lateral json_each(cartodb.CDB_Conf_GetConf('fdws')) p - LOOP - EXECUTE 'SELECT cartodb._CDB_Create_FDW($1, $2)' USING row.key, row.value; + FOR row IN SELECT p.key, p.value from lateral json_each(cartodb.CDB_Conf_GetConf('fdws')) p LOOP + EXECUTE 'SELECT cartodb._CDB_Setup_FDW($1, $2)' USING row.key, row.value; END LOOP; END - $$ - LANGUAGE PLPGSQL; +$$ +LANGUAGE PLPGSQL; -CREATE OR REPLACE FUNCTION cartodb._CDB_Create_FDW(name text) +CREATE OR REPLACE FUNCTION cartodb._CDB_Setup_FDW(fdw_name text) RETURNS void AS $BODY$ DECLARE config json; BEGIN - SELECT p.value FROM LATERAL json_each(cartodb.CDB_Conf_GetConf('fdws')) p WHERE p.key = name INTO config; - EXECUTE 'SELECT cartodb._CDB_Create_FDW($1, $2)' USING name, config; + SELECT p.value FROM LATERAL json_each(cartodb.CDB_Conf_GetConf('fdws')) p WHERE p.key = fdw_name INTO config; + EXECUTE 'SELECT cartodb._CDB_Setup_FDW($1, $2)' USING fdw_name, config; END $BODY$ -LANGUAGE plpgsql VOLATILE -SECURITY DEFINER; +LANGUAGE plpgsql VOLATILE; CREATE OR REPLACE FUNCTION cartodb.CDB_Add_Remote_Table(source text, table_name text) -RETURNS void AS + RETURNS void AS $$ BEGIN -PERFORM cartodb._CDB_Create_FDW(source); -EXECUTE FORMAT ('IMPORT FOREIGN SCHEMA %I LIMIT TO (%I) FROM SERVER %I INTO %I;', source, table_name, source, source); ---- Grant SELECT to publicuser -EXECUTE FORMAT ('GRANT SELECT ON %I.%I TO publicuser;', source, table_name); - + PERFORM cartodb._CDB_Setup_FDW(source); + EXECUTE FORMAT ('IMPORT FOREIGN SCHEMA %I LIMIT TO (%I) FROM SERVER %I INTO %I;', source, table_name, source, source); + --- Grant SELECT to publicuser + EXECUTE FORMAT ('GRANT SELECT ON %I.%I TO publicuser;', source, table_name); END $$ -LANGUAGE plpgsql -security definer; - +LANGUAGE plpgsql; From b957635e78e123adbd6e31b99a3b3bc01665952c Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Alejandro=20Mart=C3=ADnez?= Date: Thu, 4 Feb 2016 18:26:43 +0100 Subject: [PATCH 04/31] Add CDB_Get_Foreign_Updated_At function --- scripts-available/CDB_ForeignTable.sql | 22 ++++++++++++++++++++++ 1 file changed, 22 insertions(+) diff --git a/scripts-available/CDB_ForeignTable.sql b/scripts-available/CDB_ForeignTable.sql index 9e94729..c6e8e9c 100644 --- a/scripts-available/CDB_ForeignTable.sql +++ b/scripts-available/CDB_ForeignTable.sql @@ -108,3 +108,25 @@ BEGIN END $$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION cartodb.CDB_Get_Foreign_Updated_At(foreign_table regclass) + RETURNS timestamp with time zone AS +$$ +DECLARE + remote_table_name text; + fdw_schema_name text; + time timestamp with time zone; +BEGIN + -- This will turn a local foreign table (referenced as regclass) to its fully qualified text remote table reference. + WITH a AS (SELECT ftoptions FROM pg_foreign_table WHERE ftrelid=foreign_table LIMIT 1), + b as (SELECT (pg_options_to_table(ftoptions)).* FROM a) + SELECT FORMAT('%I.%I', (SELECT option_value FROM b WHERE option_name='schema_name'), (SELECT option_value FROM b WHERE option_name='table_name')) + INTO remote_table_name; + + -- We assume that the remote cdb_tablemetadata is called cdb_tablemetadata and is on the same schema as the queried table. + SELECT nspname FROM pg_class c, pg_namespace n WHERE c.oid=foreign_table AND c.relnamespace = n.oid INTO fdw_schema_name; + EXECUTE FORMAT('SELECT updated_at FROM %I.cdb_tablemetadata WHERE tabname::text=%L ORDER BY updated_at DESC LIMIT 1', fdw_schema_name, remote_table_name) INTO time + RETURN time; +END +$$ +LANGUAGE plpgsql; From 11834dfdab9309da0741ed90dd2f82f9a77fbe73 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Fri, 5 Feb 2016 10:44:55 +0100 Subject: [PATCH 05/31] Fix typo: missing semicolon --- scripts-available/CDB_ForeignTable.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/scripts-available/CDB_ForeignTable.sql b/scripts-available/CDB_ForeignTable.sql index c6e8e9c..f07e9fd 100644 --- a/scripts-available/CDB_ForeignTable.sql +++ b/scripts-available/CDB_ForeignTable.sql @@ -125,7 +125,7 @@ BEGIN -- We assume that the remote cdb_tablemetadata is called cdb_tablemetadata and is on the same schema as the queried table. SELECT nspname FROM pg_class c, pg_namespace n WHERE c.oid=foreign_table AND c.relnamespace = n.oid INTO fdw_schema_name; - EXECUTE FORMAT('SELECT updated_at FROM %I.cdb_tablemetadata WHERE tabname::text=%L ORDER BY updated_at DESC LIMIT 1', fdw_schema_name, remote_table_name) INTO time + EXECUTE FORMAT('SELECT updated_at FROM %I.cdb_tablemetadata WHERE tabname::text=%L ORDER BY updated_at DESC LIMIT 1', fdw_schema_name, remote_table_name) INTO time; RETURN time; END $$ From 8dedd2b3f4e266736a284136be087a09580222ef Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Fri, 5 Feb 2016 13:15:20 +0100 Subject: [PATCH 06/31] Fix small typos: s/name/fdw_name/ --- scripts-available/CDB_ForeignTable.sql | 8 ++++---- 1 file changed, 4 insertions(+), 4 deletions(-) diff --git a/scripts-available/CDB_ForeignTable.sql b/scripts-available/CDB_ForeignTable.sql index f07e9fd..e7bc4ad 100644 --- a/scripts-available/CDB_ForeignTable.sql +++ b/scripts-available/CDB_ForeignTable.sql @@ -38,13 +38,13 @@ BEGIN FOR row IN SELECT p.key, p.value from lateral json_each(config->'users') p LOOP -- Check if entry on pg_user_mappings exists - IF NOT EXISTS ( SELECT * FROM pg_user_mappings WHERE srvname = name AND usename = row.key ) THEN + IF NOT EXISTS ( SELECT * FROM pg_user_mappings WHERE srvname = fdw_name AND usename = row.key ) THEN EXECUTE FORMAT ('CREATE USER MAPPING FOR %I SERVER %I', row.key, fdw_name); END IF; -- Update user mapping settings FOR option IN SELECT o.key, o.value from lateral json_each_text(row.value) o LOOP - IF NOT EXISTS (WITH a AS (select split_part(unnest(umoptions), '=', 1) as options from pg_user_mappings WHERE srvname = name AND usename = row.key) SELECT * from a where options = option.key) THEN + IF NOT EXISTS (WITH a AS (select split_part(unnest(umoptions), '=', 1) as options from pg_user_mappings WHERE srvname = fdw_name AND usename = row.key) SELECT * from a where options = option.key) THEN EXECUTE FORMAT('ALTER USER MAPPING FOR %I SERVER %I OPTIONS (ADD %I %L)', row.key, fdw_name, option.key, option.value); ELSE EXECUTE FORMAT('ALTER USER MAPPING FOR %I SERVER %I OPTIONS (SET %I %L)', row.key, fdw_name, option.key, option.value); @@ -59,10 +59,10 @@ BEGIN -- Give the organization role usage permisions over the schema SELECT cartodb.CDB_Organization_Member_Group_Role_Member_Name() INTO org_role; - EXECUTE FORMAT ('GRANT USAGE ON SCHEMA %I TO %I', name, org_role); + EXECUTE FORMAT ('GRANT USAGE ON SCHEMA %I TO %I', fdw_name, org_role); -- Bring here the remote cdb_tablemetadata - IF NOT EXISTS ( SELECT * FROM PG_CLASS WHERE relnamespace = (SELECT oid FROM pg_namespace WHERE nspname='do') and relname='cdb_tablemetadata') THEN + IF NOT EXISTS ( SELECT * FROM PG_CLASS WHERE relnamespace = (SELECT oid FROM pg_namespace WHERE nspname=fdw_name) and relname='cdb_tablemetadata') THEN EXECUTE FORMAT ('IMPORT FOREIGN SCHEMA cartodb LIMIT TO (cdb_tablemetadata) FROM SERVER %I INTO %I;', fdw_name, fdw_name, fdw_name); END IF; EXECUTE FORMAT ('GRANT SELECT ON %I.cdb_tablemetadata TO %I', fdw_name, org_role); From edf79d9368b12cfda87e3150ddbd273f3e952940 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Alejandro=20Mart=C3=ADnez?= Date: Mon, 8 Feb 2016 15:45:58 +0100 Subject: [PATCH 07/31] Add remote cdb_tablemetadata manually from public schema --- scripts-available/CDB_ForeignTable.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/scripts-available/CDB_ForeignTable.sql b/scripts-available/CDB_ForeignTable.sql index e7bc4ad..85042db 100644 --- a/scripts-available/CDB_ForeignTable.sql +++ b/scripts-available/CDB_ForeignTable.sql @@ -63,7 +63,7 @@ BEGIN -- Bring here the remote cdb_tablemetadata IF NOT EXISTS ( SELECT * FROM PG_CLASS WHERE relnamespace = (SELECT oid FROM pg_namespace WHERE nspname=fdw_name) and relname='cdb_tablemetadata') THEN - EXECUTE FORMAT ('IMPORT FOREIGN SCHEMA cartodb LIMIT TO (cdb_tablemetadata) FROM SERVER %I INTO %I;', fdw_name, fdw_name, fdw_name); + EXECUTE FORMAT ('CREATE FOREIGN TABLE %I.cdb_tablemetadata (tabname regclass, updated_at timestamp with time zone) SERVER %I OPTIONS (table_name ''cdb_tablemetadata'', schema_name ''public'', updatable ''false'')', fdw_name, fdw_name); END IF; EXECUTE FORMAT ('GRANT SELECT ON %I.cdb_tablemetadata TO %I', fdw_name, org_role); From e858ddfa0b31521b5c0825b130cd407eca719963 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Alejandro=20Mart=C3=ADnez?= Date: Mon, 8 Feb 2016 15:46:25 +0100 Subject: [PATCH 08/31] Add CDB_ForeignTable specs --- test/extension/test.sh | 63 ++++++++++++++++++++++++++++++++++++++++-- 1 file changed, 60 insertions(+), 3 deletions(-) diff --git a/test/extension/test.sh b/test/extension/test.sh index 83073d9..1db083b 100755 --- a/test/extension/test.sh +++ b/test/extension/test.sh @@ -172,8 +172,7 @@ function drop_raster_table() { sql ${ROLE} "DROP TABLE ${ROLE}.${TABLENAME};" } - -function setup() { +function setup_database() { ${CMD} -c "CREATE DATABASE ${DATABASE}" sql "CREATE SCHEMA cartodb;" sql "GRANT USAGE ON SCHEMA cartodb TO public;" @@ -184,7 +183,10 @@ function setup() { ${CMD} -d ${DATABASE} -f scripts-available/CDB_Organizations.sql # trick to allow forcing a schema when loading SQL files (see: http://bit.ly/1HeLnhL) ${CMD} -d ${DATABASE} -f test/extension/run_at_cartodb_schema.sql +} +function setup() { + setup_database log_info "############################# SETUP #############################" create_role_and_schema cdb_testmember_1 @@ -199,6 +201,10 @@ function setup() { sql cdb_testmember_2 'SELECT * FROM cdb_testmember_2.bar;' } + +function tear_down_database() { + ${CMD} -c "DROP DATABASE ${DATABASE}" +} function tear_down() { log_info "########################### USER TEAR DOWN ###########################" sql cdb_testmember_1 "SELECT * FROM cartodb.CDB_Organization_Remove_Access_Permission('cdb_testmember_1', 'foo', 'cdb_testmember_2');" @@ -219,9 +225,10 @@ function tear_down() { sql 'DROP ROLE cdb_testmember_1;' sql 'DROP ROLE cdb_testmember_2;' - ${CMD} -c "DROP DATABASE ${DATABASE}" + tear_down_database } + function run_tests() { local FAILED_TESTS=() @@ -429,6 +436,56 @@ function test_cdb_querytables_happy_cases() { sql postgres 'DROP SCHEMA foo;' } +function test_foreign_tables() { + ${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryStatements.sql + ${CMD} -d ${DATABASE} -f scripts-available/CDB_QueryTables.sql + ${CMD} -d ${DATABASE} -f scripts-available/CDB_TableMetadata.sql + ${CMD} -d ${DATABASE} -f scripts-available/CDB_Conf.sql + ${CMD} -d ${DATABASE} -f scripts-available/CDB_ForeignTable.sql + + + DATABASE=fdw_target setup_database + ${CMD} -d fdw_target -f scripts-available/CDB_QueryStatements.sql + ${CMD} -d fdw_target -f scripts-available/CDB_QueryTables.sql + ${CMD} -d fdw_target -f scripts-available/CDB_TableMetadata.sql + + 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 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 public.cdb_tablemetadata TO fdw_user;' + + DATABASE=fdw_target sql postgres "SELECT cdb_tablemetadatatouch('test_fdw.foo'::regclass);" + + sql postgres "SELECT CDB_Conf_SetConf('fdws', '{\"test_fdw\": {\"server\": {\"host\": \"localhost\", \"dbname\": \"fdw_target\"}, + \"users\": {\"public\": {\"user\": \"fdw_user\", \"password\": \"foobarino\"}}}}')" + + sql postgres "SELECT CDB_Add_Remote_Table('test_fdw', 'foo')" + sql postgres "SELECT * from test_fdw.foo;" + sql postgres "SELECT n.nspname, + c.relname, + s.srvname FROM pg_catalog.pg_foreign_table ft + INNER JOIN pg_catalog.pg_class c ON c.oid = ft.ftrelid + INNER JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace + INNER JOIN pg_catalog.pg_foreign_server s ON s.oid = ft.ftserver +ORDER BY 1, 2" should "test_fdw|cdb_tablemetadata|test_fdw +test_fdw|foo|test_fdw" + + sql postgres "SELECT cartodb.CDB_Get_Foreign_Updated_At('test_fdw.foo'::regclass) < NOW()" should 't' + + sql postgres "SELECT a from test_fdw.foo LIMIT 1;" should 42 + + + 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 cdb_tablemetadata FROM fdw_user;' + DATABASE=fdw_target sql postgres 'DROP ROLE fdw_user;' + + DATABASE=fdw_target tear_down_database +} + #################################################### TESTS END HERE #################################################### run_tests $@ From 131aee1503d9b0b7a2409760d512ecd407fb0f60 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Alejandro=20Mart=C3=ADnez?= Date: Mon, 8 Feb 2016 16:35:26 +0100 Subject: [PATCH 09/31] Fully qualify function names --- test/extension/test.sh | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/test/extension/test.sh b/test/extension/test.sh index 1db083b..e87a39c 100755 --- a/test/extension/test.sh +++ b/test/extension/test.sh @@ -459,10 +459,10 @@ function test_foreign_tables() { DATABASE=fdw_target sql postgres "SELECT cdb_tablemetadatatouch('test_fdw.foo'::regclass);" - sql postgres "SELECT CDB_Conf_SetConf('fdws', '{\"test_fdw\": {\"server\": {\"host\": \"localhost\", \"dbname\": \"fdw_target\"}, + sql postgres "SELECT cartodb.CDB_Conf_SetConf('fdws', '{\"test_fdw\": {\"server\": {\"host\": \"localhost\", \"dbname\": \"fdw_target\"}, \"users\": {\"public\": {\"user\": \"fdw_user\", \"password\": \"foobarino\"}}}}')" - sql postgres "SELECT CDB_Add_Remote_Table('test_fdw', 'foo')" + sql postgres "SELECT cartodb.CDB_Add_Remote_Table('test_fdw', 'foo')" sql postgres "SELECT * from test_fdw.foo;" sql postgres "SELECT n.nspname, c.relname, From fdbad0f93c308db4805390e44c7fa9f9f52c91e4 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Alejandro=20Mart=C3=ADnez?= Date: Mon, 8 Feb 2016 17:33:41 +0100 Subject: [PATCH 10/31] Fix specs on 9.3 --- test/extension/test.sh | 14 ++++++++++++-- 1 file changed, 12 insertions(+), 2 deletions(-) diff --git a/test/extension/test.sh b/test/extension/test.sh index e87a39c..949cbe4 100755 --- a/test/extension/test.sh +++ b/test/extension/test.sh @@ -462,8 +462,18 @@ function test_foreign_tables() { sql postgres "SELECT cartodb.CDB_Conf_SetConf('fdws', '{\"test_fdw\": {\"server\": {\"host\": \"localhost\", \"dbname\": \"fdw_target\"}, \"users\": {\"public\": {\"user\": \"fdw_user\", \"password\": \"foobarino\"}}}}')" - sql postgres "SELECT cartodb.CDB_Add_Remote_Table('test_fdw', 'foo')" - sql postgres "SELECT * from test_fdw.foo;" + sql postgres "SELECT cartodb._CDB_Setup_FDW('test_fdw')" + + sql postgres "SHOW server_version_num" + if [ "$RESULT" -gt 90499 ] + then + sql postgres "SELECT cartodb.CDB_Add_Remote_Table('test_fdw', 'foo')" + sql postgres "SELECT * from test_fdw.foo;" + else + echo "NOTICE: PostgreSQL version is less than 9.5 ($RESULT). Skipping CDB_Add_Remote_Table." + sql postgres "CREATE FOREIGN TABLE test_fdw.foo (a int) SERVER test_fdw OPTIONS (table_name 'foo', schema_name 'test_fdw')" + fi + sql postgres "SELECT n.nspname, c.relname, s.srvname FROM pg_catalog.pg_foreign_table ft From 0c43fe27311443df91d804c0ad2531f4f6ca7607 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Mon, 8 Feb 2016 12:09:29 +0100 Subject: [PATCH 11/31] Define API of CDB_QueryTablesUpdatedAt --- scripts-available/CDB_QueryTables.sql | 12 ++++++++++++ 1 file changed, 12 insertions(+) diff --git a/scripts-available/CDB_QueryTables.sql b/scripts-available/CDB_QueryTables.sql index c7cfa64..aaa3f8c 100644 --- a/scripts-available/CDB_QueryTables.sql +++ b/scripts-available/CDB_QueryTables.sql @@ -76,3 +76,15 @@ BEGIN RETURN CDB_QueryTablesText(query)::name[]; END $$ LANGUAGE 'plpgsql' VOLATILE STRICT; + + +-- Return a set of {db_name, schema_name, table_name. updated_at} +CREATE OR REPLACE FUNCTION CDB_QueryTablesUpdatedAt(query text) +RETURNS TABLE(db_name text, schema_name text, table_name text, updated_at timestamp) +AS $$ +BEGIN + -- TODO: Get the tables involved in the query + -- TODO: Get the local/remote db_names involved in the query + -- TODO: Get the updated_at +END +$$ LANGUAGE 'plpgsql' VOLATILE STRICT; From c2100081847b42f1978f2702718a87975fc54a71 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Mon, 8 Feb 2016 15:54:42 +0100 Subject: [PATCH 12/31] Skeleton of a possible solution (WIP) --- scripts-available/CDB_QueryTables.sql | 60 ++++++++++++++++++++++++++- 1 file changed, 58 insertions(+), 2 deletions(-) diff --git a/scripts-available/CDB_QueryTables.sql b/scripts-available/CDB_QueryTables.sql index aaa3f8c..2862239 100644 --- a/scripts-available/CDB_QueryTables.sql +++ b/scripts-available/CDB_QueryTables.sql @@ -77,14 +77,70 @@ BEGIN END $$ LANGUAGE 'plpgsql' VOLATILE STRICT; - +-------------------------------------------------------------------------------- -- Return a set of {db_name, schema_name, table_name. updated_at} CREATE OR REPLACE FUNCTION CDB_QueryTablesUpdatedAt(query text) RETURNS TABLE(db_name text, schema_name text, table_name text, updated_at timestamp) AS $$ +DECLARE + qualified_table_names text[]; + qualified_table_name text; + ret RECORD; BEGIN - -- TODO: Get the tables involved in the query + -- Get the tables involved in the query + SELECT CDB_QueryTablesText(query) INTO qualified_table_names; + + FOREACH qualified_table_name IN ARRAY qualified_table_names LOOP + --ret.db_name := 'db_name'; + RAISE DEBUG 'hola'; + END LOOP; + + RETURN QUERY + WITH qt AS (SELECT unnest(CDB_QueryTablesText(query)) qualified_table_name) + SELECT 'db_name'::text AS db_name, 'schema_name'::text AS schema_name, qt.qualified_table_name::text AS table_name, now()::timestamp AS udpated_at + FROM qt; + + -- TODO: Get the local/remote db_names involved in the query -- TODO: Get the updated_at END $$ LANGUAGE 'plpgsql' VOLATILE STRICT; + + +-- Take a text containing "schema_name"."table_name" as input and +-- return a record of the form (db_name text, schema_name text, table_name text) +CREATE OR REPLACE FUNCTION _cdb_fqtn_from_text(schema_table_name text) +RETURNS RECORD AS $$ +DECLARE + ret RECORD; + reloid oid; + db_name text; + schema_name text; + table_name text; +BEGIN + SELECT schema_table_name::regclass INTO STRICT reloid; + + -- TODO: get if the table is local or remote + SELECT + CASE WHEN c.relkind = 'f' THEN _cdb_dbname_of_foreign_table(reloid) + ELSE current_database() + END as dbname, + n.nspname schema_name, c.relname table_name + FROM pg_catalog.pg_class c + LEFT JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid + WHERE c.oid = reloid; + + + SELECT 'my_db_name'::text, 'my_schema_name'::text, 'my_table_name'::text INTO ret; + RETURN ret; +END; +$$ LANGUAGE plpgsql; + + +CREATE OR REPLACE FUNCTION _cdb_dbname_of_foreign_table(reloid oid) +RETURNS TEXT AS $$ +BEGIN + --TODO: implement + RETURN 'cartodb_dev_user_36c4a45a-eb92-4af4-a8ff-1065ecfd041f_db'; +END; +$$ LANGUAGE plpgsql; From 1e3c7ace9959e3128e41f4a1c14a50b28c9c78e9 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Mon, 8 Feb 2016 16:19:20 +0100 Subject: [PATCH 13/31] Implementation of _cdb_dbname_of_foreign_table (WIP) --- scripts-available/CDB_QueryTables.sql | 15 ++++++++++----- 1 file changed, 10 insertions(+), 5 deletions(-) diff --git a/scripts-available/CDB_QueryTables.sql b/scripts-available/CDB_QueryTables.sql index 2862239..68a702a 100644 --- a/scripts-available/CDB_QueryTables.sql +++ b/scripts-available/CDB_QueryTables.sql @@ -78,6 +78,7 @@ END $$ LANGUAGE 'plpgsql' VOLATILE STRICT; -------------------------------------------------------------------------------- + -- Return a set of {db_name, schema_name, table_name. updated_at} CREATE OR REPLACE FUNCTION CDB_QueryTablesUpdatedAt(query text) RETURNS TABLE(db_name text, schema_name text, table_name text, updated_at timestamp) @@ -139,8 +140,12 @@ $$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION _cdb_dbname_of_foreign_table(reloid oid) RETURNS TEXT AS $$ -BEGIN - --TODO: implement - RETURN 'cartodb_dev_user_36c4a45a-eb92-4af4-a8ff-1065ecfd041f_db'; -END; -$$ LANGUAGE plpgsql; + SELECT option_value FROM pg_options_to_table(( + + SELECT fs.srvoptions + FROM pg_foreign_table ft + LEFT JOIN pg_foreign_server fs ON ft.ftserver = fs.oid + WHERE ft.ftrelid = reloid + + )) WHERE option_name='dbname'; +$$ LANGUAGE SQL; From 78a75cf22dcb3788b94600c07c0b761f8e36e06a Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Mon, 8 Feb 2016 16:38:04 +0100 Subject: [PATCH 14/31] Implementation of _cdb_fqtn_from_text (WIP) --- scripts-available/CDB_QueryTables.sql | 18 +++++++----------- 1 file changed, 7 insertions(+), 11 deletions(-) diff --git a/scripts-available/CDB_QueryTables.sql b/scripts-available/CDB_QueryTables.sql index 68a702a..442a6ae 100644 --- a/scripts-available/CDB_QueryTables.sql +++ b/scripts-available/CDB_QueryTables.sql @@ -109,30 +109,26 @@ $$ LANGUAGE 'plpgsql' VOLATILE STRICT; -- Take a text containing "schema_name"."table_name" as input and --- return a record of the form (db_name text, schema_name text, table_name text) +-- return a record of the form (dbname text, schema_name text, table_name text) CREATE OR REPLACE FUNCTION _cdb_fqtn_from_text(schema_table_name text) RETURNS RECORD AS $$ DECLARE - ret RECORD; reloid oid; - db_name text; - schema_name text; - table_name text; + ret RECORD; BEGIN SELECT schema_table_name::regclass INTO STRICT reloid; - -- TODO: get if the table is local or remote SELECT - CASE WHEN c.relkind = 'f' THEN _cdb_dbname_of_foreign_table(reloid) + (CASE WHEN c.relkind = 'f' THEN _cdb_dbname_of_foreign_table(reloid) ELSE current_database() - END as dbname, - n.nspname schema_name, c.relname table_name + END)::text AS dbname, + n.nspname::text schema_name, + c.relname::text table_name + INTO ret FROM pg_catalog.pg_class c LEFT JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE c.oid = reloid; - - SELECT 'my_db_name'::text, 'my_schema_name'::text, 'my_table_name'::text INTO ret; RETURN ret; END; $$ LANGUAGE plpgsql; From 1a12fd3b69b16094c7a1a7a470969854f865bd3a Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Mon, 8 Feb 2016 18:42:40 +0100 Subject: [PATCH 15/31] Make _cdb_fqtn_from_text return a table with type instead of a record --- scripts-available/CDB_QueryTables.sql | 8 ++------ 1 file changed, 2 insertions(+), 6 deletions(-) diff --git a/scripts-available/CDB_QueryTables.sql b/scripts-available/CDB_QueryTables.sql index 442a6ae..5361572 100644 --- a/scripts-available/CDB_QueryTables.sql +++ b/scripts-available/CDB_QueryTables.sql @@ -111,25 +111,21 @@ $$ LANGUAGE 'plpgsql' VOLATILE STRICT; -- Take a text containing "schema_name"."table_name" as input and -- return a record of the form (dbname text, schema_name text, table_name text) CREATE OR REPLACE FUNCTION _cdb_fqtn_from_text(schema_table_name text) -RETURNS RECORD AS $$ +RETURNS TABLE(dbname text, schema_name text, table_name text) AS $$ DECLARE reloid oid; - ret RECORD; BEGIN SELECT schema_table_name::regclass INTO STRICT reloid; - SELECT + RETURN QUERY SELECT (CASE WHEN c.relkind = 'f' THEN _cdb_dbname_of_foreign_table(reloid) ELSE current_database() END)::text AS dbname, n.nspname::text schema_name, c.relname::text table_name - INTO ret FROM pg_catalog.pg_class c LEFT JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid WHERE c.oid = reloid; - - RETURN ret; END; $$ LANGUAGE plpgsql; From a074f4df5d39f48f62ad602035cbd55afbfd3d36 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Mon, 8 Feb 2016 18:43:25 +0100 Subject: [PATCH 16/31] Adapt CDB_QueryTablesUpdatedAt to _cdb_fqtn_from_text --- scripts-available/CDB_QueryTables.sql | 26 +++++++++----------------- 1 file changed, 9 insertions(+), 17 deletions(-) diff --git a/scripts-available/CDB_QueryTables.sql b/scripts-available/CDB_QueryTables.sql index 5361572..5a50e64 100644 --- a/scripts-available/CDB_QueryTables.sql +++ b/scripts-available/CDB_QueryTables.sql @@ -79,30 +79,22 @@ $$ LANGUAGE 'plpgsql' VOLATILE STRICT; -------------------------------------------------------------------------------- --- Return a set of {db_name, schema_name, table_name. updated_at} +-- Return a set of {dbname, schema_name, table_name. updated_at} CREATE OR REPLACE FUNCTION CDB_QueryTablesUpdatedAt(query text) RETURNS TABLE(db_name text, schema_name text, table_name text, updated_at timestamp) AS $$ -DECLARE - qualified_table_names text[]; - qualified_table_name text; - ret RECORD; BEGIN - -- Get the tables involved in the query - SELECT CDB_QueryTablesText(query) INTO qualified_table_names; - - FOREACH qualified_table_name IN ARRAY qualified_table_names LOOP - --ret.db_name := 'db_name'; - RAISE DEBUG 'hola'; - END LOOP; RETURN QUERY - WITH qt AS (SELECT unnest(CDB_QueryTablesText(query)) qualified_table_name) - SELECT 'db_name'::text AS db_name, 'schema_name'::text AS schema_name, qt.qualified_table_name::text AS table_name, now()::timestamp AS udpated_at - FROM qt; + WITH query_tables AS ( + SELECT unnest(CDB_QueryTablesText(query)) schema_table_name + ), fqtn AS ( + SELECT (_cdb_fqtn_from_text(schema_table_name)).* + FROM query_tables + ) + SELECT fqtn.dbname, fqtn.schema_name, fqtn.table_name, now()::timestamp AS udpated_at + FROM fqtn; - - -- TODO: Get the local/remote db_names involved in the query -- TODO: Get the updated_at END $$ LANGUAGE 'plpgsql' VOLATILE STRICT; From 0f21db51b622a725a2e8dcf548d52e5dda733567 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Mon, 8 Feb 2016 19:24:09 +0100 Subject: [PATCH 17/31] Simplify the code and get the updated_at --- scripts-available/CDB_QueryTables.sql | 48 +++++++++++---------------- 1 file changed, 20 insertions(+), 28 deletions(-) diff --git a/scripts-available/CDB_QueryTables.sql b/scripts-available/CDB_QueryTables.sql index 5a50e64..ae480e8 100644 --- a/scripts-available/CDB_QueryTables.sql +++ b/scripts-available/CDB_QueryTables.sql @@ -81,47 +81,39 @@ $$ LANGUAGE 'plpgsql' VOLATILE STRICT; -- Return a set of {dbname, schema_name, table_name. updated_at} CREATE OR REPLACE FUNCTION CDB_QueryTablesUpdatedAt(query text) -RETURNS TABLE(db_name text, schema_name text, table_name text, updated_at timestamp) +RETURNS TABLE(db_name text, schema_name text, table_name text, updated_at timestamptz) AS $$ BEGIN RETURN QUERY WITH query_tables AS ( SELECT unnest(CDB_QueryTablesText(query)) schema_table_name - ), fqtn AS ( - SELECT (_cdb_fqtn_from_text(schema_table_name)).* + ), query_tables_oid AS ( + SELECT schema_table_name, schema_table_name::regclass::oid AS reloid FROM query_tables + ), + fqtn AS ( + SELECT + (CASE WHEN c.relkind = 'f' THEN _cdb_dbname_of_foreign_table(query_tables_oid.reloid) + ELSE current_database() + END)::text AS dbname, + n.nspname::text schema_name, + c.relname::text table_name, + c.relkind, + query_tables_oid.reloid + FROM query_tables_oid, pg_catalog.pg_class c + LEFT JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid + WHERE c.oid = query_tables_oid.reloid ) - SELECT fqtn.dbname, fqtn.schema_name, fqtn.table_name, now()::timestamp AS udpated_at + SELECT fqtn.dbname, fqtn.schema_name, fqtn.table_name, + (CASE WHEN relkind = 'f' THEN CDB_Get_Foreign_Updated_At(reloid) + ELSE (SELECT md.updated_at FROM CDB_TableMetadata md WHERE tabname = reloid) + END) AS updated_at FROM fqtn; - - -- TODO: Get the updated_at END $$ LANGUAGE 'plpgsql' VOLATILE STRICT; --- Take a text containing "schema_name"."table_name" as input and --- return a record of the form (dbname text, schema_name text, table_name text) -CREATE OR REPLACE FUNCTION _cdb_fqtn_from_text(schema_table_name text) -RETURNS TABLE(dbname text, schema_name text, table_name text) AS $$ -DECLARE - reloid oid; -BEGIN - SELECT schema_table_name::regclass INTO STRICT reloid; - - RETURN QUERY SELECT - (CASE WHEN c.relkind = 'f' THEN _cdb_dbname_of_foreign_table(reloid) - ELSE current_database() - END)::text AS dbname, - n.nspname::text schema_name, - c.relname::text table_name - FROM pg_catalog.pg_class c - LEFT JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid - WHERE c.oid = reloid; -END; -$$ LANGUAGE plpgsql; - - CREATE OR REPLACE FUNCTION _cdb_dbname_of_foreign_table(reloid oid) RETURNS TEXT AS $$ SELECT option_value FROM pg_options_to_table(( From ec34b8ee287a8b8db9f9ece11652ce471c1875ca Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Mon, 8 Feb 2016 19:28:57 +0100 Subject: [PATCH 18/31] Minor changes: use plain SQL func --- scripts-available/CDB_QueryTables.sql | 8 ++------ 1 file changed, 2 insertions(+), 6 deletions(-) diff --git a/scripts-available/CDB_QueryTables.sql b/scripts-available/CDB_QueryTables.sql index ae480e8..418c649 100644 --- a/scripts-available/CDB_QueryTables.sql +++ b/scripts-available/CDB_QueryTables.sql @@ -83,9 +83,6 @@ $$ LANGUAGE 'plpgsql' VOLATILE STRICT; CREATE OR REPLACE FUNCTION CDB_QueryTablesUpdatedAt(query text) RETURNS TABLE(db_name text, schema_name text, table_name text, updated_at timestamptz) AS $$ -BEGIN - - RETURN QUERY WITH query_tables AS ( SELECT unnest(CDB_QueryTablesText(query)) schema_table_name ), query_tables_oid AS ( @@ -107,11 +104,10 @@ BEGIN ) SELECT fqtn.dbname, fqtn.schema_name, fqtn.table_name, (CASE WHEN relkind = 'f' THEN CDB_Get_Foreign_Updated_At(reloid) - ELSE (SELECT md.updated_at FROM CDB_TableMetadata md WHERE tabname = reloid) + ELSE (SELECT md.updated_at FROM CDB_TableMetadata md WHERE md.tabname = reloid) END) AS updated_at FROM fqtn; -END -$$ LANGUAGE 'plpgsql' VOLATILE STRICT; +$$ LANGUAGE SQL; CREATE OR REPLACE FUNCTION _cdb_dbname_of_foreign_table(reloid oid) From 276b5cf9ea31431c139fb32e653fd02395bf3acb Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Tue, 9 Feb 2016 13:29:04 +0100 Subject: [PATCH 19/31] Rename func to CDB_QueryTables_Updated_At s/CDB_QueryTablesUpdatedAt/CDB_QueryTables_Updated_At and also add a bit more inline doc. --- scripts-available/CDB_QueryTables.sql | 5 +++-- 1 file changed, 3 insertions(+), 2 deletions(-) diff --git a/scripts-available/CDB_QueryTables.sql b/scripts-available/CDB_QueryTables.sql index 418c649..0abeb59 100644 --- a/scripts-available/CDB_QueryTables.sql +++ b/scripts-available/CDB_QueryTables.sql @@ -79,8 +79,9 @@ $$ LANGUAGE 'plpgsql' VOLATILE STRICT; -------------------------------------------------------------------------------- --- Return a set of {dbname, schema_name, table_name. updated_at} -CREATE OR REPLACE FUNCTION CDB_QueryTablesUpdatedAt(query text) +-- Return a set of (dbname, schema_name, table_name, updated_at) +-- This assumes the local (schema_name, table_name) maps to the remote one with the same name +CREATE OR REPLACE FUNCTION CDB_QueryTables_Updated_At(query text) RETURNS TABLE(db_name text, schema_name text, table_name text, updated_at timestamptz) AS $$ WITH query_tables AS ( From eb84dd04c9d842f6293a6c4381e20152b808f121 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Tue, 9 Feb 2016 13:30:00 +0100 Subject: [PATCH 20/31] Add func CDB_Last_Updated_Time --- scripts-available/CDB_QueryTables.sql | 19 +++++++++++++++++++ 1 file changed, 19 insertions(+) diff --git a/scripts-available/CDB_QueryTables.sql b/scripts-available/CDB_QueryTables.sql index 0abeb59..80ef620 100644 --- a/scripts-available/CDB_QueryTables.sql +++ b/scripts-available/CDB_QueryTables.sql @@ -122,3 +122,22 @@ RETURNS TEXT AS $$ )) WHERE option_name='dbname'; $$ LANGUAGE SQL; + + +-- TODO: move to the right place +-- Return the last updated time of a set of tables +CREATE OR REPLACE FUNCTION CDB_Last_Updated_Time(tables text[]) +RETURNS timestamptz AS $$ + WITH t AS ( + SELECT unnest(tables) AS schema_table_name + ), t_oid AS ( + SELECT (t.schema_table_name)::regclass::oid as reloid FROM t + ), t_updated_at AS ( + SELECT + (CASE WHEN relkind = 'f' THEN CDB_Get_Foreign_Updated_At(reloid) + ELSE (SELECT md.updated_at FROM CDB_TableMetadata md WHERE md.tabname = reloid) + END) AS updated_at + FROM t_oid + LEFT JOIN pg_catalog.pg_class c ON c.oid = reloid + ) SELECT max(updated_at) FROM t_updated_at; +$$ LANGUAGE SQL; From ecbdb4a430343099482b6fee0543ea6cb6f6ccaf Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Tue, 9 Feb 2016 13:40:18 +0100 Subject: [PATCH 21/31] Move fdw-aware functions to CDB_ForeignTable.sql --- scripts-available/CDB_ForeignTable.sql | 66 ++++++++++++++++++++++++++ scripts-available/CDB_QueryTables.sql | 65 ------------------------- 2 files changed, 66 insertions(+), 65 deletions(-) diff --git a/scripts-available/CDB_ForeignTable.sql b/scripts-available/CDB_ForeignTable.sql index 85042db..6367512 100644 --- a/scripts-available/CDB_ForeignTable.sql +++ b/scripts-available/CDB_ForeignTable.sql @@ -130,3 +130,69 @@ BEGIN END $$ LANGUAGE plpgsql; + + +-- Return a set of (dbname, schema_name, table_name, updated_at) +-- It is aware of foreign tables +-- It assumes the local (schema_name, table_name) map to the remote ones with the same name +CREATE OR REPLACE FUNCTION cartodb.CDB_QueryTables_Updated_At(query text) +RETURNS TABLE(db_name text, schema_name text, table_name text, updated_at timestamptz) +AS $$ + WITH query_tables AS ( + SELECT unnest(CDB_QueryTablesText(query)) schema_table_name + ), query_tables_oid AS ( + SELECT schema_table_name, schema_table_name::regclass::oid AS reloid + FROM query_tables + ), + fqtn AS ( + SELECT + (CASE WHEN c.relkind = 'f' THEN _cdb_dbname_of_foreign_table(query_tables_oid.reloid) + ELSE current_database() + END)::text AS dbname, + n.nspname::text schema_name, + c.relname::text table_name, + c.relkind, + query_tables_oid.reloid + FROM query_tables_oid, pg_catalog.pg_class c + LEFT JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid + WHERE c.oid = query_tables_oid.reloid + ) + SELECT fqtn.dbname, fqtn.schema_name, fqtn.table_name, + (CASE WHEN relkind = 'f' THEN CDB_Get_Foreign_Updated_At(reloid) + ELSE (SELECT md.updated_at FROM cartodb.CDB_TableMetadata md WHERE md.tabname = reloid) + END) AS updated_at + FROM fqtn; +$$ LANGUAGE SQL; + + +CREATE OR REPLACE FUNCTION cartodb._cdb_dbname_of_foreign_table(reloid oid) +RETURNS TEXT AS $$ + SELECT option_value FROM pg_options_to_table(( + + SELECT fs.srvoptions + FROM pg_foreign_table ft + LEFT JOIN pg_foreign_server fs ON ft.ftserver = fs.oid + WHERE ft.ftrelid = reloid + + )) WHERE option_name='dbname'; +$$ LANGUAGE SQL; + + +-- Return the last updated time of a set of tables +-- It is aware of foreign tables +-- It assumes the local (schema_name, table_name) map to the remote ones with the same name +CREATE OR REPLACE FUNCTION cartodb.CDB_Last_Updated_Time(tables text[]) +RETURNS timestamptz AS $$ + WITH t AS ( + SELECT unnest(tables) AS schema_table_name + ), t_oid AS ( + SELECT (t.schema_table_name)::regclass::oid as reloid FROM t + ), t_updated_at AS ( + SELECT + (CASE WHEN relkind = 'f' THEN CDB_Get_Foreign_Updated_At(reloid) + ELSE (SELECT md.updated_at FROM cartodb.CDB_TableMetadata md WHERE md.tabname = reloid) + END) AS updated_at + FROM t_oid + LEFT JOIN pg_catalog.pg_class c ON c.oid = reloid + ) SELECT max(updated_at) FROM t_updated_at; +$$ LANGUAGE SQL; diff --git a/scripts-available/CDB_QueryTables.sql b/scripts-available/CDB_QueryTables.sql index 80ef620..c7cfa64 100644 --- a/scripts-available/CDB_QueryTables.sql +++ b/scripts-available/CDB_QueryTables.sql @@ -76,68 +76,3 @@ BEGIN RETURN CDB_QueryTablesText(query)::name[]; END $$ LANGUAGE 'plpgsql' VOLATILE STRICT; - --------------------------------------------------------------------------------- - --- Return a set of (dbname, schema_name, table_name, updated_at) --- This assumes the local (schema_name, table_name) maps to the remote one with the same name -CREATE OR REPLACE FUNCTION CDB_QueryTables_Updated_At(query text) -RETURNS TABLE(db_name text, schema_name text, table_name text, updated_at timestamptz) -AS $$ - WITH query_tables AS ( - SELECT unnest(CDB_QueryTablesText(query)) schema_table_name - ), query_tables_oid AS ( - SELECT schema_table_name, schema_table_name::regclass::oid AS reloid - FROM query_tables - ), - fqtn AS ( - SELECT - (CASE WHEN c.relkind = 'f' THEN _cdb_dbname_of_foreign_table(query_tables_oid.reloid) - ELSE current_database() - END)::text AS dbname, - n.nspname::text schema_name, - c.relname::text table_name, - c.relkind, - query_tables_oid.reloid - FROM query_tables_oid, pg_catalog.pg_class c - LEFT JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid - WHERE c.oid = query_tables_oid.reloid - ) - SELECT fqtn.dbname, fqtn.schema_name, fqtn.table_name, - (CASE WHEN relkind = 'f' THEN CDB_Get_Foreign_Updated_At(reloid) - ELSE (SELECT md.updated_at FROM CDB_TableMetadata md WHERE md.tabname = reloid) - END) AS updated_at - FROM fqtn; -$$ LANGUAGE SQL; - - -CREATE OR REPLACE FUNCTION _cdb_dbname_of_foreign_table(reloid oid) -RETURNS TEXT AS $$ - SELECT option_value FROM pg_options_to_table(( - - SELECT fs.srvoptions - FROM pg_foreign_table ft - LEFT JOIN pg_foreign_server fs ON ft.ftserver = fs.oid - WHERE ft.ftrelid = reloid - - )) WHERE option_name='dbname'; -$$ LANGUAGE SQL; - - --- TODO: move to the right place --- Return the last updated time of a set of tables -CREATE OR REPLACE FUNCTION CDB_Last_Updated_Time(tables text[]) -RETURNS timestamptz AS $$ - WITH t AS ( - SELECT unnest(tables) AS schema_table_name - ), t_oid AS ( - SELECT (t.schema_table_name)::regclass::oid as reloid FROM t - ), t_updated_at AS ( - SELECT - (CASE WHEN relkind = 'f' THEN CDB_Get_Foreign_Updated_At(reloid) - ELSE (SELECT md.updated_at FROM CDB_TableMetadata md WHERE md.tabname = reloid) - END) AS updated_at - FROM t_oid - LEFT JOIN pg_catalog.pg_class c ON c.oid = reloid - ) SELECT max(updated_at) FROM t_updated_at; -$$ LANGUAGE SQL; From 1c637f86896212357d6a4489307d0f8da9d52ca0 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Tue, 9 Feb 2016 16:38:11 +0100 Subject: [PATCH 22/31] Small fixes: qualify cartodb function calls --- scripts-available/CDB_ForeignTable.sql | 8 ++++---- 1 file changed, 4 insertions(+), 4 deletions(-) diff --git a/scripts-available/CDB_ForeignTable.sql b/scripts-available/CDB_ForeignTable.sql index 6367512..b75fd46 100644 --- a/scripts-available/CDB_ForeignTable.sql +++ b/scripts-available/CDB_ForeignTable.sql @@ -136,7 +136,7 @@ LANGUAGE plpgsql; -- It is aware of foreign tables -- It assumes the local (schema_name, table_name) map to the remote ones with the same name CREATE OR REPLACE FUNCTION cartodb.CDB_QueryTables_Updated_At(query text) -RETURNS TABLE(db_name text, schema_name text, table_name text, updated_at timestamptz) +RETURNS TABLE(dbname text, schema_name text, table_name text, updated_at timestamptz) AS $$ WITH query_tables AS ( SELECT unnest(CDB_QueryTablesText(query)) schema_table_name @@ -146,7 +146,7 @@ AS $$ ), fqtn AS ( SELECT - (CASE WHEN c.relkind = 'f' THEN _cdb_dbname_of_foreign_table(query_tables_oid.reloid) + (CASE WHEN c.relkind = 'f' THEN cartodb._cdb_dbname_of_foreign_table(query_tables_oid.reloid) ELSE current_database() END)::text AS dbname, n.nspname::text schema_name, @@ -158,7 +158,7 @@ AS $$ WHERE c.oid = query_tables_oid.reloid ) SELECT fqtn.dbname, fqtn.schema_name, fqtn.table_name, - (CASE WHEN relkind = 'f' THEN CDB_Get_Foreign_Updated_At(reloid) + (CASE WHEN relkind = 'f' THEN cartodb.CDB_Get_Foreign_Updated_At(reloid) ELSE (SELECT md.updated_at FROM cartodb.CDB_TableMetadata md WHERE md.tabname = reloid) END) AS updated_at FROM fqtn; @@ -189,7 +189,7 @@ RETURNS timestamptz AS $$ SELECT (t.schema_table_name)::regclass::oid as reloid FROM t ), t_updated_at AS ( SELECT - (CASE WHEN relkind = 'f' THEN CDB_Get_Foreign_Updated_At(reloid) + (CASE WHEN relkind = 'f' THEN cartodb.CDB_Get_Foreign_Updated_At(reloid) ELSE (SELECT md.updated_at FROM cartodb.CDB_TableMetadata md WHERE md.tabname = reloid) END) AS updated_at FROM t_oid From d59b826d37dde21b4ddd2f8989c8adfe34e72187 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Tue, 9 Feb 2016 17:11:16 +0100 Subject: [PATCH 23/31] Fix silly bug: ordering of functions --- scripts-available/CDB_ForeignTable.sql | 26 +++++++++++++------------- 1 file changed, 13 insertions(+), 13 deletions(-) diff --git a/scripts-available/CDB_ForeignTable.sql b/scripts-available/CDB_ForeignTable.sql index b75fd46..5729288 100644 --- a/scripts-available/CDB_ForeignTable.sql +++ b/scripts-available/CDB_ForeignTable.sql @@ -132,6 +132,19 @@ $$ LANGUAGE plpgsql; +CREATE OR REPLACE FUNCTION cartodb._cdb_dbname_of_foreign_table(reloid oid) +RETURNS TEXT AS $$ + SELECT option_value FROM pg_options_to_table(( + + SELECT fs.srvoptions + FROM pg_foreign_table ft + LEFT JOIN pg_foreign_server fs ON ft.ftserver = fs.oid + WHERE ft.ftrelid = reloid + + )) WHERE option_name='dbname'; +$$ LANGUAGE SQL; + + -- Return a set of (dbname, schema_name, table_name, updated_at) -- It is aware of foreign tables -- It assumes the local (schema_name, table_name) map to the remote ones with the same name @@ -165,19 +178,6 @@ AS $$ $$ LANGUAGE SQL; -CREATE OR REPLACE FUNCTION cartodb._cdb_dbname_of_foreign_table(reloid oid) -RETURNS TEXT AS $$ - SELECT option_value FROM pg_options_to_table(( - - SELECT fs.srvoptions - FROM pg_foreign_table ft - LEFT JOIN pg_foreign_server fs ON ft.ftserver = fs.oid - WHERE ft.ftrelid = reloid - - )) WHERE option_name='dbname'; -$$ LANGUAGE SQL; - - -- Return the last updated time of a set of tables -- It is aware of foreign tables -- It assumes the local (schema_name, table_name) map to the remote ones with the same name From cd4ad29e39c8e437cb3875aaa2995a5d808c2869 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Tue, 9 Feb 2016 18:49:17 +0100 Subject: [PATCH 24/31] Remove schema when selecting from CDB_TableMetadata to ease testing. When creating CDB_TableMetadata it is always put in cartodb when done from the extension, but for tests it is done in public. --- scripts-available/CDB_ForeignTable.sql | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/scripts-available/CDB_ForeignTable.sql b/scripts-available/CDB_ForeignTable.sql index 5729288..a7ef87e 100644 --- a/scripts-available/CDB_ForeignTable.sql +++ b/scripts-available/CDB_ForeignTable.sql @@ -172,7 +172,7 @@ AS $$ ) SELECT fqtn.dbname, fqtn.schema_name, fqtn.table_name, (CASE WHEN relkind = 'f' THEN cartodb.CDB_Get_Foreign_Updated_At(reloid) - ELSE (SELECT md.updated_at FROM cartodb.CDB_TableMetadata md WHERE md.tabname = reloid) + ELSE (SELECT md.updated_at FROM CDB_TableMetadata md WHERE md.tabname = reloid) END) AS updated_at FROM fqtn; $$ LANGUAGE SQL; @@ -190,7 +190,7 @@ RETURNS timestamptz AS $$ ), t_updated_at AS ( SELECT (CASE WHEN relkind = 'f' THEN cartodb.CDB_Get_Foreign_Updated_At(reloid) - ELSE (SELECT md.updated_at FROM cartodb.CDB_TableMetadata md WHERE md.tabname = reloid) + ELSE (SELECT md.updated_at FROM CDB_TableMetadata md WHERE md.tabname = reloid) END) AS updated_at FROM t_oid LEFT JOIN pg_catalog.pg_class c ON c.oid = reloid From 2bce771488a47d3d689fcd422ee008533da7d187 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Tue, 9 Feb 2016 18:50:50 +0100 Subject: [PATCH 25/31] Add some tests Tests for: * CDB_QueryTables_Updated_At * CDB_Last_Updated_Time --- test/extension/test.sh | 13 +++++++++++++ 1 file changed, 13 insertions(+) diff --git a/test/extension/test.sh b/test/extension/test.sh index 949cbe4..cf9f830 100755 --- a/test/extension/test.sh +++ b/test/extension/test.sh @@ -487,6 +487,19 @@ test_fdw|foo|test_fdw" sql postgres "SELECT a from test_fdw.foo LIMIT 1;" should 42 + # Check function CDB_QueryTables_Updated_At + sql postgres 'CREATE TABLE local (b int);' + sql postgres 'INSERT INTO local (b) VALUES (43);' + sql postgres "SELECT cdb_tablemetadatatouch('public.local'::regclass);" + local query='$query$ SELECT * FROM test_fdw.foo, local $query$::text' + sql postgres "SELECT dbname, schema_name, table_name FROM cartodb.CDB_QueryTables_Updated_At(${query}) ORDER BY dbname;" should 'fdw_target|test_fdw|foo +test_extension|public|local' + sql postgres "SELECT table_name FROM cartodb.CDB_QueryTables_Updated_At(${query}) order by updated_at;" should 'foo +local' + + # Check function CDB_Last_Updated_Time + sql postgres "SELECT cartodb.CDB_Last_Updated_Time('{test_fdw.foo,public.local}'::text[]) < now()" should 't' + sql postgres "SELECT cartodb.CDB_Last_Updated_Time('{test_fdw.foo,public.local}'::text[]) > (now() - interval '1 minute')" should 't' 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;' From 06036e2fe800d138ef3f0d38d73f5fcf38057f61 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Wed, 10 Feb 2016 18:58:01 +0100 Subject: [PATCH 26/31] Quote identifiers returned by CDB_QueryTables_Updated_At --- scripts-available/CDB_ForeignTable.sql | 11 ++++++----- test/extension/test.sh | 9 +++++++++ 2 files changed, 15 insertions(+), 5 deletions(-) diff --git a/scripts-available/CDB_ForeignTable.sql b/scripts-available/CDB_ForeignTable.sql index a7ef87e..f39e1f8 100644 --- a/scripts-available/CDB_ForeignTable.sql +++ b/scripts-available/CDB_ForeignTable.sql @@ -159,11 +159,12 @@ AS $$ ), fqtn AS ( SELECT - (CASE WHEN c.relkind = 'f' THEN cartodb._cdb_dbname_of_foreign_table(query_tables_oid.reloid) - ELSE current_database() - END)::text AS dbname, - n.nspname::text schema_name, - c.relname::text table_name, + quote_ident( + (CASE WHEN c.relkind = 'f' THEN cartodb._cdb_dbname_of_foreign_table(query_tables_oid.reloid) + ELSE current_database() + END)::text) AS dbname, + quote_ident(n.nspname::text) schema_name, + quote_ident(c.relname::text) table_name, c.relkind, query_tables_oid.reloid FROM query_tables_oid, pg_catalog.pg_class c diff --git a/test/extension/test.sh b/test/extension/test.sh index cf9f830..37a5406 100755 --- a/test/extension/test.sh +++ b/test/extension/test.sh @@ -501,6 +501,15 @@ local' sql postgres "SELECT cartodb.CDB_Last_Updated_Time('{test_fdw.foo,public.local}'::text[]) < now()" should 't' sql postgres "SELECT cartodb.CDB_Last_Updated_Time('{test_fdw.foo,public.local}'::text[]) > (now() - interval '1 minute')" should 't' + # Check we quote names on output as needed (as CDB_QueryTablesText does) + sql postgres 'CREATE TABLE "local-table-with-dashes" (c int)'; + sql postgres 'INSERT INTO "local-table-with-dashes" (c) VALUES (44)'; + sql postgres "SELECT cdb_tablemetadatatouch('public.local-table-with-dashes'::regclass);" + query='$query$ SELECT * FROM test_fdw.foo, local, public."local-table-with-dashes" $query$::text' + sql postgres "SELECT dbname, schema_name, table_name FROM cartodb.CDB_QueryTables_Updated_At(${query}) ORDER BY dbname, schema_name, table_name;" should 'fdw_target|test_fdw|foo +test_extension|public|local +test_extension|public|"local-table-with-dashes"' + 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 cdb_tablemetadata FROM fdw_user;' From 9596e8d9bcf28cba4e9f6a2e24c01bded95d8c48 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Wed, 10 Feb 2016 19:10:57 +0100 Subject: [PATCH 27/31] A couple checks for quoted idents in CDB_Last_Updated_Time --- test/extension/test.sh | 4 ++++ 1 file changed, 4 insertions(+) diff --git a/test/extension/test.sh b/test/extension/test.sh index 37a5406..ece0ae9 100755 --- a/test/extension/test.sh +++ b/test/extension/test.sh @@ -510,6 +510,10 @@ local' test_extension|public|local test_extension|public|"local-table-with-dashes"' + # Check CDB_Last_Updated_Time supports quoted identifiers + sql postgres "SELECT cartodb.CDB_Last_Updated_Time(ARRAY['test_extension.public.\"local-table-with-dashes\"']::text[]) < now()" should 't' + sql postgres "SELECT cartodb.CDB_Last_Updated_Time(ARRAY['test_extension.public.\"local-table-with-dashes\"']::text[]) > (now() - interval '1 minute')" should 't' + 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 cdb_tablemetadata FROM fdw_user;' From 2f26b44142b8acf71299dfa94eb4d300fed080c4 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Thu, 11 Feb 2016 16:09:01 +0100 Subject: [PATCH 28/31] tDo not quote dbname identifier Turns out that for caching it is our standard not to have the dbname quoted. --- scripts-available/CDB_ForeignTable.sql | 7 +++---- 1 file changed, 3 insertions(+), 4 deletions(-) diff --git a/scripts-available/CDB_ForeignTable.sql b/scripts-available/CDB_ForeignTable.sql index f39e1f8..72333b0 100644 --- a/scripts-available/CDB_ForeignTable.sql +++ b/scripts-available/CDB_ForeignTable.sql @@ -159,10 +159,9 @@ AS $$ ), fqtn AS ( SELECT - quote_ident( - (CASE WHEN c.relkind = 'f' THEN cartodb._cdb_dbname_of_foreign_table(query_tables_oid.reloid) - ELSE current_database() - END)::text) AS dbname, + (CASE WHEN c.relkind = 'f' THEN cartodb._cdb_dbname_of_foreign_table(query_tables_oid.reloid) + ELSE current_database() + END)::text AS dbname, quote_ident(n.nspname::text) schema_name, quote_ident(c.relname::text) table_name, c.relkind, From 56fed123929e846e44d88231332826b720d88f87 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Alejandro=20Mart=C3=ADnez?= Date: Thu, 11 Feb 2016 19:16:00 +0100 Subject: [PATCH 29/31] Add CDB_TableMetadata_Text view as a proxy to access FDW tablemetadata --- Makefile | 1 + scripts-available/CDB_ForeignTable.sql | 4 ++-- scripts-available/CDB_TableMetadata.sql | 5 +++++ test/extension/test.sh | 10 ++++++++-- 4 files changed, 16 insertions(+), 4 deletions(-) diff --git a/Makefile b/Makefile index ffab669..0d932d3 100644 --- a/Makefile +++ b/Makefile @@ -93,6 +93,7 @@ $(EXTENSION)--$(EXTVERSION).sql: $(CDBSCRIPTS) cartodb_version.sql Makefile cat $(CDBSCRIPTS) | \ $(SED) -e 's/public\./cartodb./g' \ -e 's/:DATABASE_USERNAME/cdb_org_admin/g' >> $@ + -e "s/''public''/''cartodb''/g" >> $@ echo "GRANT USAGE ON SCHEMA cartodb TO public;" >> $@ cat cartodb_version.sql >> $@ diff --git a/scripts-available/CDB_ForeignTable.sql b/scripts-available/CDB_ForeignTable.sql index 72333b0..5b1c894 100644 --- a/scripts-available/CDB_ForeignTable.sql +++ b/scripts-available/CDB_ForeignTable.sql @@ -63,7 +63,7 @@ BEGIN -- Bring here the remote cdb_tablemetadata IF NOT EXISTS ( SELECT * FROM PG_CLASS WHERE relnamespace = (SELECT oid FROM pg_namespace WHERE nspname=fdw_name) and relname='cdb_tablemetadata') THEN - EXECUTE FORMAT ('CREATE FOREIGN TABLE %I.cdb_tablemetadata (tabname regclass, updated_at timestamp with time zone) SERVER %I OPTIONS (table_name ''cdb_tablemetadata'', schema_name ''public'', updatable ''false'')', fdw_name, fdw_name); + EXECUTE FORMAT ('CREATE FOREIGN TABLE %I.cdb_tablemetadata (tabname text, updated_at timestamp with time zone) SERVER %I OPTIONS (table_name ''cdb_tablemetadata_text'', schema_name ''public'', updatable ''false'')', fdw_name, fdw_name); END IF; EXECUTE FORMAT ('GRANT SELECT ON %I.cdb_tablemetadata TO %I', fdw_name, org_role); @@ -125,7 +125,7 @@ BEGIN -- We assume that the remote cdb_tablemetadata is called cdb_tablemetadata and is on the same schema as the queried table. SELECT nspname FROM pg_class c, pg_namespace n WHERE c.oid=foreign_table AND c.relnamespace = n.oid INTO fdw_schema_name; - EXECUTE FORMAT('SELECT updated_at FROM %I.cdb_tablemetadata WHERE tabname::text=%L ORDER BY updated_at DESC LIMIT 1', fdw_schema_name, remote_table_name) INTO time; + EXECUTE FORMAT('SELECT updated_at FROM %I.cdb_tablemetadata WHERE tabname=%L ORDER BY updated_at DESC LIMIT 1', fdw_schema_name, remote_table_name) INTO time; RETURN time; END $$ diff --git a/scripts-available/CDB_TableMetadata.sql b/scripts-available/CDB_TableMetadata.sql index d91f798..6f65606 100644 --- a/scripts-available/CDB_TableMetadata.sql +++ b/scripts-available/CDB_TableMetadata.sql @@ -5,6 +5,11 @@ CREATE TABLE IF NOT EXISTS updated_at timestamp with time zone not null default now() ); +CREATE OR REPLACE VIEW public.CDB_TableMetadata_Text AS + SELECT FORMAT('%I.%I', n.nspname::text, c.relname::text) tabname, updated_at + FROM public.CDB_TableMetadata, pg_catalog.pg_class c + LEFT JOIN pg_catalog.pg_namespace n ON c.relnamespace = n.oid; + -- No one can see this -- Updates are only possible trough the security definer trigger -- GRANT SELECT ON public.CDB_TableMetadata TO public; diff --git a/test/extension/test.sh b/test/extension/test.sh index ece0ae9..389eba3 100755 --- a/test/extension/test.sh +++ b/test/extension/test.sh @@ -452,12 +452,16 @@ function test_foreign_tables() { 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 public.cdb_tablemetadata 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;' 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 cartodb.CDB_Conf_SetConf('fdws', '{\"test_fdw\": {\"server\": {\"host\": \"localhost\", \"dbname\": \"fdw_target\"}, \"users\": {\"public\": {\"user\": \"fdw_user\", \"password\": \"foobarino\"}}}}')" @@ -516,9 +520,11 @@ test_extension|public|"local-table-with-dashes"' 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 cdb_tablemetadata 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 } From a0fe55bd5dee91d7dbbf57c285fba442d25e6896 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Fri, 12 Feb 2016 11:27:26 +0100 Subject: [PATCH 30/31] Add a small bit of func doc about the quoting --- scripts-available/CDB_ForeignTable.sql | 1 + 1 file changed, 1 insertion(+) diff --git a/scripts-available/CDB_ForeignTable.sql b/scripts-available/CDB_ForeignTable.sql index 5b1c894..b03d284 100644 --- a/scripts-available/CDB_ForeignTable.sql +++ b/scripts-available/CDB_ForeignTable.sql @@ -148,6 +148,7 @@ $$ LANGUAGE SQL; -- Return a set of (dbname, schema_name, table_name, updated_at) -- It is aware of foreign tables -- It assumes the local (schema_name, table_name) map to the remote ones with the same name +-- Note: dbname is never quoted whereas schema and table names are when needed. CREATE OR REPLACE FUNCTION cartodb.CDB_QueryTables_Updated_At(query text) RETURNS TABLE(dbname text, schema_name text, table_name text, updated_at timestamptz) AS $$ From d2450ff3612e5fbf80c7fa311acd256a09306365 Mon Sep 17 00:00:00 2001 From: Rafa de la Torre Date: Fri, 12 Feb 2016 11:34:04 +0100 Subject: [PATCH 31/31] Fix small typo in makefile --- Makefile | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/Makefile b/Makefile index 0d932d3..2607828 100644 --- a/Makefile +++ b/Makefile @@ -92,7 +92,7 @@ $(EXTENSION)--$(EXTVERSION).sql: $(CDBSCRIPTS) cartodb_version.sql Makefile echo '\echo Use "CREATE EXTENSION $(EXTENSION)" to load this file. \quit' > $@ cat $(CDBSCRIPTS) | \ $(SED) -e 's/public\./cartodb./g' \ - -e 's/:DATABASE_USERNAME/cdb_org_admin/g' >> $@ + -e 's/:DATABASE_USERNAME/cdb_org_admin/g' \ -e "s/''public''/''cartodb''/g" >> $@ echo "GRANT USAGE ON SCHEMA cartodb TO public;" >> $@ cat cartodb_version.sql >> $@