Compare commits
44 Commits
| Author | SHA1 | Date | |
|---|---|---|---|
|
|
afa52aa92b | ||
|
|
746dbea434 | ||
|
|
f9bd469ea9 | ||
|
|
402d97daa6 | ||
|
|
e41d2ec019 | ||
|
|
3c460f1a85 | ||
|
|
076207c49c | ||
|
|
ce1e9ac41c | ||
|
|
0f33ee8b22 | ||
|
|
a32dea0282 | ||
|
|
3a255df9d0 | ||
|
|
c4e2549dc8 | ||
|
|
2e9f642378 | ||
|
|
99096d41e0 | ||
|
|
3a10ef7e76 | ||
|
|
a20676f391 | ||
|
|
37004db047 | ||
|
|
1189d70b2a | ||
|
|
8cfc8e65cf | ||
|
|
32db4fd81e | ||
|
|
a1e3e9a8df | ||
|
|
6e34e16b8d | ||
|
|
70220e04c1 | ||
|
|
a5cb9f268d | ||
|
|
d2d909145d | ||
|
|
34dec227c4 | ||
|
|
99e92e2505 | ||
|
|
c58a084102 | ||
|
|
b7907ff82f | ||
|
|
12d955075a | ||
|
|
10a4d85c01 | ||
|
|
524bb6ad42 | ||
|
|
4da89d8abd | ||
|
|
c7311ba48e | ||
|
|
2eae7876e2 | ||
|
|
91c3b86d45 | ||
|
|
f55d789c41 | ||
|
|
3eb8ab24d8 | ||
|
|
0f1c98c743 | ||
|
|
8ecd2cd5e2 | ||
|
|
f4be59cae0 | ||
|
|
fe66b2865a | ||
|
|
2be9d2d81a | ||
|
|
5744921065 |
@@ -24,7 +24,7 @@ before_install:
|
||||
- sudo apt-get install -y --allow-unauthenticated postgresql-$POSTGRESQL_VERSION-postgis-$POSTGIS_VERSION postgresql-$POSTGRESQL_VERSION-postgis-$POSTGIS_VERSION-scripts postgis postgresql-plpython-$POSTGRESQL_VERSION
|
||||
- sudo pg_dropcluster --stop $POSTGRESQL_VERSION main
|
||||
- sudo rm -rf /etc/postgresql/$POSTGRESQL_VERSION /var/lib/postgresql/$POSTGRESQL_VERSION
|
||||
- sudo pg_createcluster -u postgres $POSTGRESQL_VERSION main -- -A trust
|
||||
- sudo pg_createcluster -u postgres $POSTGRESQL_VERSION main -- --auth-local trust --auth-host password
|
||||
- sudo /etc/init.d/postgresql start $POSTGRESQL_VERSION || sudo journalctl -xe
|
||||
- sudo pip install redis==2.4.9
|
||||
script:
|
||||
|
||||
12
Makefile
12
Makefile
@@ -1,7 +1,7 @@
|
||||
# cartodb/Makefile
|
||||
|
||||
EXTENSION = cartodb
|
||||
EXTVERSION = 0.28.1
|
||||
EXTVERSION = 0.30.0
|
||||
|
||||
SED = sed
|
||||
AWK = awk
|
||||
@@ -101,6 +101,8 @@ UPGRADABLE = \
|
||||
0.27.2 \
|
||||
0.28.0 \
|
||||
0.28.1 \
|
||||
0.29.0 \
|
||||
0.30.0 \
|
||||
$(EXTVERSION)dev \
|
||||
$(EXTVERSION)next \
|
||||
$(END)
|
||||
@@ -130,6 +132,8 @@ PG_CONFIG = pg_config
|
||||
PGXS := $(shell $(PG_CONFIG) --pgxs)
|
||||
include $(PGXS)
|
||||
|
||||
PG_VERSION := $(shell $(PG_CONFIG) --version | $(AWK) '{split($$2,a,"."); print a[1]}')
|
||||
|
||||
$(EXTENSION)--$(EXTVERSION).sql: $(CDBSCRIPTS) cartodb_version.sql Makefile
|
||||
echo '\echo Use "CREATE EXTENSION $(EXTENSION)" to load this file. \quit' > $@
|
||||
cat $(CDBSCRIPTS) | \
|
||||
@@ -171,7 +175,11 @@ legacy_regress: $(REGRESS_OLD) Makefile
|
||||
$(SED) -e 's/@@VERSION@@/$(EXTVERSION)/' -e 's/@extschema@/cartodb/g' -e "s/@postgisschema@/public/g" >> $${of}; \
|
||||
exp=expected/test/$${tn}.out; \
|
||||
echo '\set ECHO none' > $${exp}; \
|
||||
cat test/$${tn}_expect >> $${exp}; \
|
||||
if [[ -f "test/$${tn}_expect.pg$(PG_VERSION)" ]]; then \
|
||||
cat test/$${tn}_expect.pg$(PG_VERSION) >> $${exp}; \
|
||||
else \
|
||||
cat test/$${tn}_expect >> $${exp}; \
|
||||
fi \
|
||||
done
|
||||
|
||||
test_organization:
|
||||
|
||||
9
NEWS.md
9
NEWS.md
@@ -1,3 +1,12 @@
|
||||
0.30.0 (2019-07-17)
|
||||
* Added new admin functions to connect CARTO with user FDW's (#369)
|
||||
|
||||
0.29.0 (2019-07-15)
|
||||
* Added new function CDB_OAuth:
|
||||
* Install event trigger to check for table/view/sequence/function creation
|
||||
* Reassign the ownership of new objects to a defined role in the cdb_conf
|
||||
* Changed MakeFile to support different expects for differents PG versions
|
||||
|
||||
0.28.1 (2019-07-04)
|
||||
* Avoid temporary tables creation in CDB_SyncTable (#366)
|
||||
* Make CDB_Get_Foreign_Updated_At robust to missing CDB_TableMetadata (#362)
|
||||
|
||||
@@ -139,6 +139,176 @@ $$
|
||||
LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE;
|
||||
|
||||
|
||||
-- Produce a valid DB name for objects created for the user FDW's
|
||||
CREATE OR REPLACE FUNCTION @extschema@.__CDB_User_FDW_Object_Names(fdw_input_name NAME)
|
||||
RETURNS NAME AS $$
|
||||
-- Note on input we use %s and on output we use %I, in order to
|
||||
-- avoid double escaping
|
||||
SELECT format('cdb_fdw_%s', fdw_input_name)::NAME;
|
||||
$$
|
||||
LANGUAGE sql IMMUTABLE PARALLEL SAFE;
|
||||
|
||||
-- A function to set up a user-defined foreign data server
|
||||
-- It does not read from CDB_Conf.
|
||||
-- Only superuser roles can invoke it successfully
|
||||
--
|
||||
-- Sample call:
|
||||
-- SELECT cartodb.CDB_SetUp_User_PG_FDW_Server('amazon', '{
|
||||
-- "server": {
|
||||
-- "extensions": "postgis",
|
||||
-- "dbname": "testdb",
|
||||
-- "host": "myhostname.us-east-2.rds.amazonaws.com",
|
||||
-- "port": "5432"
|
||||
-- },
|
||||
-- "user_mapping": {
|
||||
-- "user": "fdw_user",
|
||||
-- "password": "secret"
|
||||
-- }
|
||||
-- }');
|
||||
--
|
||||
-- Underneath it will:
|
||||
-- * Set up postgresql_fdw
|
||||
-- * Create a server with the name 'cdb_fdw_amazon'
|
||||
-- * Create a role called 'cdb_fdw_amazon' to manage access
|
||||
-- * Create a user mapping with that role 'cdb_fdw_amazon'
|
||||
-- * Create a schema 'cdb_fdw_amazon' as a convenience to set up all foreign
|
||||
-- tables over there
|
||||
--
|
||||
-- It is the responsibility of the superuser to grant that role to either:
|
||||
-- * Nobody
|
||||
-- * Specific roles: GRANT amazon TO role_name;
|
||||
-- * Members of the organization: SELECT cartodb.CDB_Organization_Grant_Role('cdb_fdw_amazon');
|
||||
-- * The publicuser: GRANT cdb_fdw_amazon TO publicuser;
|
||||
CREATE OR REPLACE FUNCTION @extschema@._CDB_SetUp_User_PG_FDW_Server(fdw_input_name NAME, config json)
|
||||
RETURNS void AS $$
|
||||
DECLARE
|
||||
row record;
|
||||
option record;
|
||||
fdw_objects_name NAME := @extschema@.__CDB_User_FDW_Object_Names(fdw_input_name);
|
||||
BEGIN
|
||||
-- TODO: refactor with original function
|
||||
-- This function tries to be as idempotent as possible, by not creating anything more than once
|
||||
-- (not even using IF NOT EXIST to avoid throwing warnings)
|
||||
IF NOT EXISTS ( SELECT * FROM pg_extension WHERE extname = 'postgres_fdw') THEN
|
||||
CREATE EXTENSION postgres_fdw;
|
||||
RAISE NOTICE 'Created postgres_fdw extension';
|
||||
END IF;
|
||||
-- Create FDW first if it does not exist
|
||||
IF NOT EXISTS ( SELECT * FROM pg_foreign_server WHERE srvname = fdw_objects_name)
|
||||
THEN
|
||||
EXECUTE FORMAT('CREATE SERVER %I FOREIGN DATA WRAPPER postgres_fdw', fdw_objects_name);
|
||||
RAISE NOTICE 'Created server % using postgres_fdw', fdw_objects_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=fdw_objects_name) SELECT * from a where options = row.key)
|
||||
THEN
|
||||
EXECUTE FORMAT('ALTER SERVER %I OPTIONS (ADD %I %L)', fdw_objects_name, row.key, row.value);
|
||||
ELSE
|
||||
EXECUTE FORMAT('ALTER SERVER %I OPTIONS (SET %I %L)', fdw_objects_name, row.key, row.value);
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
-- Create specific role for this
|
||||
IF NOT EXISTS ( SELECT 1 FROM pg_roles WHERE rolname = fdw_objects_name) THEN
|
||||
EXECUTE format('CREATE ROLE %I NOLOGIN', fdw_objects_name);
|
||||
RAISE NOTICE 'Created special role % to access the correponding FDW', fdw_objects_name;
|
||||
END IF;
|
||||
|
||||
-- Transfer ownership of the server to the fdw role
|
||||
EXECUTE format('ALTER SERVER %I OWNER TO %I', fdw_objects_name, fdw_objects_name);
|
||||
|
||||
-- Create user mapping
|
||||
-- NOTE: we use a PUBLIC user mapping but control access to the SERVER
|
||||
-- so that we don't need to create a mapping for every user nor store credentials elsewhere
|
||||
IF NOT EXISTS ( SELECT * FROM pg_user_mappings WHERE srvname = fdw_objects_name AND usename = 'public' ) THEN
|
||||
EXECUTE FORMAT ('CREATE USER MAPPING FOR public SERVER %I', fdw_objects_name);
|
||||
RAISE NOTICE 'Created user mapping for accesing foreign server %', fdw_objects_name;
|
||||
END IF;
|
||||
|
||||
-- Update user mapping settings
|
||||
FOR option IN SELECT o.key, o.value from lateral json_each_text(config->'user_mapping') o LOOP
|
||||
IF NOT EXISTS (WITH a AS (select split_part(unnest(umoptions), '=', 1) as options from pg_user_mappings WHERE srvname = fdw_objects_name AND usename = 'public') SELECT * from a where options = option.key) THEN
|
||||
EXECUTE FORMAT('ALTER USER MAPPING FOR PUBLIC SERVER %I OPTIONS (ADD %I %L)', fdw_objects_name, option.key, option.value);
|
||||
ELSE
|
||||
EXECUTE FORMAT('ALTER USER MAPPING FOR PUBLIC SERVER %I OPTIONS (SET %I %L)', fdw_objects_name, option.key, option.value);
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
-- Grant usage on the wrapper and server to the fdw role
|
||||
EXECUTE FORMAT ('GRANT USAGE ON FOREIGN DATA WRAPPER postgres_fdw TO %I', fdw_objects_name);
|
||||
RAISE NOTICE 'Granted usage on the postgres_fdw to the role %', fdw_objects_name;
|
||||
EXECUTE FORMAT ('GRANT USAGE ON FOREIGN SERVER %I TO %I', fdw_objects_name, fdw_objects_name);
|
||||
RAISE NOTICE 'Granted usage on the foreign server to the role %', fdw_objects_name;
|
||||
|
||||
-- Create schema if it does not exist.
|
||||
IF NOT EXISTS ( SELECT * from pg_namespace WHERE nspname=fdw_objects_name) THEN
|
||||
EXECUTE FORMAT ('CREATE SCHEMA %I', fdw_objects_name);
|
||||
RAISE NOTICE 'Created schema % to host foreign tables', fdw_objects_name;
|
||||
END IF;
|
||||
|
||||
-- Give the fdw role ownership over the schema
|
||||
EXECUTE FORMAT ('ALTER SCHEMA %I OWNER TO %I', fdw_objects_name, fdw_objects_name);
|
||||
RAISE NOTICE 'Gave ownership on the schema % to %', fdw_objects_name, fdw_objects_name;
|
||||
|
||||
-- TODO: Bring here the remote cdb_tablemetadata
|
||||
END
|
||||
$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE;
|
||||
|
||||
|
||||
-- A function to drop a user-defined foreign server and all related objects
|
||||
-- It does not read from CDB_Conf
|
||||
-- It must be executed with a superuser role to succeed
|
||||
--
|
||||
-- Sample call:
|
||||
-- SELECT cartodb.CDB_Drop_User_PG_FDW_Server('amazon')
|
||||
--
|
||||
-- Note: if there's any dependent object (i.e. foreign table) this call will fail
|
||||
CREATE OR REPLACE FUNCTION @extschema@._CDB_Drop_User_PG_FDW_Server(fdw_input_name NAME, force boolean = false)
|
||||
RETURNS void AS $$
|
||||
DECLARE
|
||||
fdw_objects_name NAME := @extschema@.__CDB_User_FDW_Object_Names(fdw_input_name);
|
||||
cascade_clause NAME;
|
||||
BEGIN
|
||||
CASE force
|
||||
WHEN true THEN
|
||||
cascade_clause := 'CASCADE';
|
||||
ELSE
|
||||
cascade_clause := 'RESTRICT';
|
||||
END CASE;
|
||||
|
||||
EXECUTE FORMAT ('DROP SCHEMA %I %s', fdw_objects_name, cascade_clause);
|
||||
RAISE NOTICE 'Dropped schema %', fdw_objects_name;
|
||||
EXECUTE FORMAT ('DROP USER MAPPING FOR public SERVER %I', fdw_objects_name);
|
||||
RAISE NOTICE 'Dropped user mapping for server %', fdw_objects_name;
|
||||
EXECUTE FORMAT ('DROP SERVER %I %s', fdw_objects_name, cascade_clause);
|
||||
RAISE NOTICE 'Dropped foreign server %', fdw_objects_name;
|
||||
EXECUTE FORMAT ('REVOKE USAGE ON FOREIGN DATA WRAPPER postgres_fdw FROM %I %s', fdw_objects_name, cascade_clause);
|
||||
RAISE NOTICE 'Revoked usage on postgres_fdw from %', fdw_objects_name;
|
||||
EXECUTE FORMAT ('DROP ROLE %I', fdw_objects_name);
|
||||
RAISE NOTICE 'Dropped role %', fdw_objects_name;
|
||||
END
|
||||
$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE;
|
||||
|
||||
|
||||
-- Set up a user foreign table
|
||||
-- E.g:
|
||||
-- SELECT cartodb.CDB_SetUp_User_PG_FDW_Table('amazon', 'carto_lite', 'mytable');
|
||||
-- SELECT * FROM amazon.my_table;
|
||||
CREATE OR REPLACE FUNCTION @extschema@.CDB_SetUp_User_PG_FDW_Table(fdw_input_name NAME, foreign_schema NAME, table_name NAME)
|
||||
RETURNS void AS $$
|
||||
DECLARE
|
||||
fdw_objects_name NAME := @extschema@.__CDB_User_FDW_Object_Names(fdw_input_name);
|
||||
BEGIN
|
||||
EXECUTE FORMAT ('IMPORT FOREIGN SCHEMA %I LIMIT TO (%I) FROM SERVER %I INTO %I;', foreign_schema, table_name, fdw_objects_name, fdw_objects_name);
|
||||
--- Grant SELECT to fdw role
|
||||
EXECUTE FORMAT ('GRANT SELECT ON %I.%I TO %I;', fdw_objects_name, table_name, fdw_objects_name);
|
||||
END
|
||||
$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION @extschema@._cdb_dbname_of_foreign_table(reloid oid)
|
||||
RETURNS TEXT AS $$
|
||||
SELECT option_value FROM pg_options_to_table((
|
||||
|
||||
53
scripts-available/CDB_OAuth.sql
Normal file
53
scripts-available/CDB_OAuth.sql
Normal file
@@ -0,0 +1,53 @@
|
||||
-- Function that reassign the owner of a table to their ownership_role
|
||||
CREATE OR REPLACE FUNCTION @extschema@.CDB_OAuthReassignTableOwnerOnCreation()
|
||||
RETURNS event_trigger
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
obj record;
|
||||
owner_role text;
|
||||
creator_role text;
|
||||
BEGIN
|
||||
FOR obj IN SELECT * FROM pg_event_trigger_ddl_commands()
|
||||
LOOP
|
||||
RAISE DEBUG '% ddl object: % % % %',
|
||||
tg_tag,
|
||||
obj.command_tag,
|
||||
obj.object_type,
|
||||
obj.schema_name,
|
||||
obj.object_identity;
|
||||
SELECT rolname FROM pg_class JOIN pg_roles ON relowner = pg_roles.oid WHERE pg_class.oid = obj.objid INTO creator_role;
|
||||
SELECT value->>'ownership_role_name' from cdb_conf where key = 'api_keys_' || creator_role INTO owner_role;
|
||||
IF owner_role IS NULL OR owner_role = '' THEN
|
||||
CONTINUE;
|
||||
ELSE
|
||||
EXECUTE 'ALTER ' || obj.object_type || ' ' || obj.object_identity || ' OWNER TO ' || QUOTE_IDENT(owner_role);
|
||||
EXECUTE 'GRANT ALL ON ' || obj.object_identity || ' TO ' || QUOTE_IDENT(creator_role);
|
||||
RAISE DEBUG 'Changing ownership from % to %', creator_role, owner_role;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE;
|
||||
|
||||
-- Creates the trigger on DDL events in order to reassign the owner
|
||||
CREATE OR REPLACE FUNCTION @extschema@.CDB_EnableOAuthReassignTablesTrigger()
|
||||
RETURNS void
|
||||
AS $$
|
||||
BEGIN
|
||||
DROP EVENT TRIGGER IF EXISTS oauth_reassign_tables_trigger;
|
||||
|
||||
CREATE EVENT TRIGGER oauth_reassign_tables_trigger
|
||||
ON ddl_command_end
|
||||
WHEN TAG IN ('CREATE TABLE', 'CREATE TABLE AS', 'SELECT INTO', 'CREATE VIEW', 'CREATE FOREIGN TABLE', 'CREATE MATERIALIZED VIEW', 'CREATE SEQUENCE', 'CREATE FUNCTION')
|
||||
EXECUTE PROCEDURE @extschema@.CDB_OAuthReassignTableOwnerOnCreation();
|
||||
END;
|
||||
$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE;
|
||||
|
||||
-- Deletes the trigger on DDL events in order to reassign the owner
|
||||
CREATE OR REPLACE FUNCTION @extschema@.CDB_DisableOAuthReassignTablesTrigger()
|
||||
RETURNS void
|
||||
AS $$
|
||||
BEGIN
|
||||
DROP EVENT TRIGGER IF EXISTS oauth_reassign_tables_trigger;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE;
|
||||
@@ -169,3 +169,30 @@ BEGIN
|
||||
EXECUTE 'SELECT @extschema@.CDB_Organization_Remove_Access_Permission(''' || from_schema || ''', ''' || table_name || ''', ''' || @extschema@.CDB_Organization_Member_Group_Role_Member_Name() || ''');';
|
||||
END
|
||||
$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE;
|
||||
|
||||
|
||||
--------------------------------------------------------------------------------
|
||||
-- Role management
|
||||
--------------------------------------------------------------------------------
|
||||
CREATE OR REPLACE
|
||||
FUNCTION @extschema@.CDB_Organization_Grant_Role(role_name name)
|
||||
RETURNS VOID AS $$
|
||||
DECLARE
|
||||
org_role TEXT;
|
||||
BEGIN
|
||||
org_role := @extschema@.CDB_Organization_Member_Group_Role_Member_Name();
|
||||
EXECUTE format('GRANT %I TO %I', role_name, org_role);
|
||||
END
|
||||
$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE;
|
||||
|
||||
|
||||
CREATE OR REPLACE
|
||||
FUNCTION @extschema@.CDB_Organization_Revoke_Role(role_name name)
|
||||
RETURNS VOID AS $$
|
||||
DECLARE
|
||||
org_role TEXT;
|
||||
BEGIN
|
||||
org_role := @extschema@.CDB_Organization_Member_Group_Role_Member_Name();
|
||||
EXECUTE format('REVOKE %I FROM %I', role_name, org_role);
|
||||
END
|
||||
$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE;
|
||||
|
||||
1
scripts-enabled/300-CDB_OAuth.sql
Symbolic link
1
scripts-enabled/300-CDB_OAuth.sql
Symbolic link
@@ -0,0 +1 @@
|
||||
../scripts-available/CDB_OAuth.sql
|
||||
177
test/CDB_OAuth.sql
Normal file
177
test/CDB_OAuth.sql
Normal file
@@ -0,0 +1,177 @@
|
||||
-- Create user and enable OAuth event trigger
|
||||
\set QUIET on
|
||||
SET client_min_messages TO error;
|
||||
DROP ROLE IF EXISTS "creator_role";
|
||||
CREATE ROLE "creator_role" LOGIN;
|
||||
DROP ROLE IF EXISTS "ownership_role";
|
||||
CREATE ROLE "ownership_role" LOGIN;
|
||||
GRANT ALL ON SCHEMA cartodb TO "creator_role";
|
||||
SELECT CDB_Conf_SetConf('api_keys_creator_role', '{"username": "creator_role", "permissions":[]}');
|
||||
SET SESSION AUTHORIZATION "creator_role";
|
||||
SET client_min_messages TO notice;
|
||||
\set QUIET off
|
||||
|
||||
-- First part without event trigger
|
||||
|
||||
CREATE TABLE test(id INT);
|
||||
INSERT INTO test VALUES(1);
|
||||
CREATE TABLE test_tablesas AS SELECT * FROM test;
|
||||
CREATE VIEW test_view AS SELECT * FROM test;
|
||||
CREATE MATERIALIZED VIEW test_mview AS SELECT * FROM test;
|
||||
SELECT * INTO test_selectinto FROM test;
|
||||
|
||||
SELECT * FROM test;
|
||||
SELECT * FROM test_tablesas;
|
||||
SELECT * FROM test_view;
|
||||
SELECT * FROM test_mview;
|
||||
SELECT * FROM test_selectinto;
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION "ownership_role";
|
||||
\set QUIET off
|
||||
|
||||
SELECT * FROM test;
|
||||
SELECT * FROM test_tablesas;
|
||||
SELECT * FROM test_view;
|
||||
SELECT * FROM test_mview;
|
||||
SELECT * FROM test_selectinto;
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION "creator_role";
|
||||
\set QUIET off
|
||||
|
||||
DROP TABLE test_tablesas;
|
||||
DROP VIEW test_view;
|
||||
DROP MATERIALIZED VIEW test_mview;
|
||||
DROP TABLE test_selectinto;
|
||||
DROP TABLE test;
|
||||
|
||||
-- Second part with event trigger but without ownership_role_name in cdb_conf
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION postgres;
|
||||
SELECT CDB_EnableOAuthReassignTablesTrigger();
|
||||
SET SESSION AUTHORIZATION "creator_role";
|
||||
\set QUIET off
|
||||
|
||||
CREATE TABLE test2(id INT);
|
||||
INSERT INTO test2 VALUES(1);
|
||||
CREATE TABLE test2_tablesas AS SELECT * FROM test2;
|
||||
CREATE VIEW test2_view AS SELECT * FROM test2;
|
||||
CREATE MATERIALIZED VIEW test2_mview AS SELECT * FROM test2;
|
||||
SELECT * INTO test2_selectinto FROM test2;
|
||||
|
||||
SELECT * FROM test2;
|
||||
SELECT * FROM test2_tablesas;
|
||||
SELECT * FROM test2_view;
|
||||
SELECT * FROM test2_mview;
|
||||
SELECT * FROM test2_selectinto;
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION "ownership_role";
|
||||
\set QUIET off
|
||||
|
||||
SELECT * FROM test2;
|
||||
SELECT * FROM test2_tablesas;
|
||||
SELECT * FROM test2_view;
|
||||
SELECT * FROM test2_mview;
|
||||
SELECT * FROM test2_selectinto;
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION "creator_role";
|
||||
\set QUIET off
|
||||
|
||||
DROP TABLE test2_tablesas;
|
||||
DROP VIEW test2_view;
|
||||
DROP MATERIALIZED VIEW test2_mview;
|
||||
DROP TABLE test2_selectinto;
|
||||
DROP TABLE test2;
|
||||
|
||||
-- Third part with event trigger but with empty ownership_role_name in cdb_conf
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION postgres;
|
||||
SELECT CDB_Conf_SetConf('api_keys_creator_role', '{"username": "creator_role", "permissions":[], "ownership_role_name": ""}');
|
||||
SET SESSION AUTHORIZATION "creator_role";
|
||||
\set QUIET off
|
||||
|
||||
CREATE TABLE test3(id INT);
|
||||
INSERT INTO test3 VALUES(1);
|
||||
CREATE TABLE test3_tablesas AS SELECT * FROM test3;
|
||||
CREATE VIEW test3_view AS SELECT * FROM test3;
|
||||
CREATE MATERIALIZED VIEW test3_mview AS SELECT * FROM test3;
|
||||
SELECT * INTO test3_selectinto FROM test3;
|
||||
|
||||
SELECT * FROM test3;
|
||||
SELECT * FROM test3_tablesas;
|
||||
SELECT * FROM test3_view;
|
||||
SELECT * FROM test3_mview;
|
||||
SELECT * FROM test3_selectinto;
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION "ownership_role";
|
||||
\set QUIET off
|
||||
|
||||
SELECT * FROM test3;
|
||||
SELECT * FROM test3_tablesas;
|
||||
SELECT * FROM test3_view;
|
||||
SELECT * FROM test3_mview;
|
||||
SELECT * FROM test3_selectinto;
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION "creator_role";
|
||||
\set QUIET off
|
||||
|
||||
DROP TABLE test3_tablesas;
|
||||
DROP VIEW test3_view;
|
||||
DROP MATERIALIZED VIEW test3_mview;
|
||||
DROP TABLE test3_selectinto;
|
||||
DROP TABLE test3;
|
||||
|
||||
-- Fourth part with the event trigger active and configured
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION postgres;
|
||||
SELECT CDB_Conf_SetConf('api_keys_creator_role', '{"username": "creator_role", "permissions":[], "ownership_role_name": "ownership_role"}');
|
||||
SET SESSION AUTHORIZATION "creator_role";
|
||||
\set QUIET off
|
||||
|
||||
CREATE TABLE test4(id INT);
|
||||
INSERT INTO test4 VALUES(1);
|
||||
CREATE TABLE test4_tablesas AS SELECT * FROM test4;
|
||||
CREATE VIEW test4_view AS SELECT * FROM test4;
|
||||
CREATE MATERIALIZED VIEW test4_mview AS SELECT * FROM test4;
|
||||
SELECT * INTO test4_selectinto FROM test4;
|
||||
|
||||
SELECT * FROM test4;
|
||||
SELECT * FROM test4_tablesas;
|
||||
SELECT * FROM test4_view;
|
||||
SELECT * FROM test4_mview;
|
||||
SELECT * FROM test4_selectinto;
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION "ownership_role";
|
||||
\set QUIET off
|
||||
|
||||
SELECT * FROM test4;
|
||||
SELECT * FROM test4_tablesas;
|
||||
SELECT * FROM test4_view;
|
||||
SELECT * FROM test4_mview;
|
||||
SELECT * FROM test4_selectinto;
|
||||
|
||||
-- Ownership role drops the tables
|
||||
DROP TABLE test4_tablesas;
|
||||
DROP VIEW test4_view;
|
||||
DROP MATERIALIZED VIEW test4_mview;
|
||||
DROP TABLE test4_selectinto;
|
||||
DROP TABLE test4;
|
||||
|
||||
-- Cleanup
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION postgres;
|
||||
SELECT CDB_DisableOAuthReassignTablesTrigger();
|
||||
DROP ROLE "ownership_role";
|
||||
REVOKE ALL ON SCHEMA cartodb FROM "creator_role";
|
||||
DROP ROLE "creator_role";
|
||||
DELETE FROM cdb_conf WHERE key = 'api_keys_creator_role';
|
||||
\set QUIET off
|
||||
90
test/CDB_OAuth_expect
Normal file
90
test/CDB_OAuth_expect
Normal file
@@ -0,0 +1,90 @@
|
||||
|
||||
CREATE TABLE
|
||||
INSERT 0 1
|
||||
SELECT 1
|
||||
CREATE VIEW
|
||||
SELECT 1
|
||||
SELECT 1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
ERROR: permission denied for relation test
|
||||
ERROR: permission denied for relation test_tablesas
|
||||
ERROR: permission denied for relation test_view
|
||||
ERROR: permission denied for relation test_mview
|
||||
ERROR: permission denied for relation test_selectinto
|
||||
DROP TABLE
|
||||
DROP VIEW
|
||||
DROP MATERIALIZED VIEW
|
||||
DROP TABLE
|
||||
DROP TABLE
|
||||
NOTICE: event trigger "oauth_reassign_tables_trigger" does not exist, skipping
|
||||
|
||||
CREATE TABLE
|
||||
INSERT 0 1
|
||||
SELECT 1
|
||||
CREATE VIEW
|
||||
SELECT 1
|
||||
SELECT 1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
ERROR: permission denied for relation test2
|
||||
ERROR: permission denied for relation test2_tablesas
|
||||
ERROR: permission denied for relation test2_view
|
||||
ERROR: permission denied for relation test2_mview
|
||||
ERROR: permission denied for relation test2_selectinto
|
||||
DROP TABLE
|
||||
DROP VIEW
|
||||
DROP MATERIALIZED VIEW
|
||||
DROP TABLE
|
||||
DROP TABLE
|
||||
|
||||
CREATE TABLE
|
||||
INSERT 0 1
|
||||
SELECT 1
|
||||
CREATE VIEW
|
||||
SELECT 1
|
||||
SELECT 1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
ERROR: permission denied for relation test3
|
||||
ERROR: permission denied for relation test3_tablesas
|
||||
ERROR: permission denied for relation test3_view
|
||||
ERROR: permission denied for relation test3_mview
|
||||
ERROR: permission denied for relation test3_selectinto
|
||||
DROP TABLE
|
||||
DROP VIEW
|
||||
DROP MATERIALIZED VIEW
|
||||
DROP TABLE
|
||||
DROP TABLE
|
||||
|
||||
CREATE TABLE
|
||||
INSERT 0 1
|
||||
SELECT 1
|
||||
CREATE VIEW
|
||||
SELECT 1
|
||||
SELECT 1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
DROP TABLE
|
||||
DROP VIEW
|
||||
DROP MATERIALIZED VIEW
|
||||
DROP TABLE
|
||||
DROP TABLE
|
||||
|
||||
90
test/CDB_OAuth_expect.pg11
Normal file
90
test/CDB_OAuth_expect.pg11
Normal file
@@ -0,0 +1,90 @@
|
||||
|
||||
CREATE TABLE
|
||||
INSERT 0 1
|
||||
SELECT 1
|
||||
CREATE VIEW
|
||||
SELECT 1
|
||||
SELECT 1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
ERROR: permission denied for table test
|
||||
ERROR: permission denied for table test_tablesas
|
||||
ERROR: permission denied for view test_view
|
||||
ERROR: permission denied for materialized view test_mview
|
||||
ERROR: permission denied for table test_selectinto
|
||||
DROP TABLE
|
||||
DROP VIEW
|
||||
DROP MATERIALIZED VIEW
|
||||
DROP TABLE
|
||||
DROP TABLE
|
||||
NOTICE: event trigger "oauth_reassign_tables_trigger" does not exist, skipping
|
||||
|
||||
CREATE TABLE
|
||||
INSERT 0 1
|
||||
SELECT 1
|
||||
CREATE VIEW
|
||||
SELECT 1
|
||||
SELECT 1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
ERROR: permission denied for table test2
|
||||
ERROR: permission denied for table test2_tablesas
|
||||
ERROR: permission denied for view test2_view
|
||||
ERROR: permission denied for materialized view test2_mview
|
||||
ERROR: permission denied for table test2_selectinto
|
||||
DROP TABLE
|
||||
DROP VIEW
|
||||
DROP MATERIALIZED VIEW
|
||||
DROP TABLE
|
||||
DROP TABLE
|
||||
|
||||
CREATE TABLE
|
||||
INSERT 0 1
|
||||
SELECT 1
|
||||
CREATE VIEW
|
||||
SELECT 1
|
||||
SELECT 1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
ERROR: permission denied for table test3
|
||||
ERROR: permission denied for table test3_tablesas
|
||||
ERROR: permission denied for view test3_view
|
||||
ERROR: permission denied for materialized view test3_mview
|
||||
ERROR: permission denied for table test3_selectinto
|
||||
DROP TABLE
|
||||
DROP VIEW
|
||||
DROP MATERIALIZED VIEW
|
||||
DROP TABLE
|
||||
DROP TABLE
|
||||
|
||||
CREATE TABLE
|
||||
INSERT 0 1
|
||||
SELECT 1
|
||||
CREATE VIEW
|
||||
SELECT 1
|
||||
SELECT 1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
1
|
||||
DROP TABLE
|
||||
DROP VIEW
|
||||
DROP MATERIALIZED VIEW
|
||||
DROP TABLE
|
||||
DROP TABLE
|
||||
|
||||
@@ -6,6 +6,14 @@ Example, to add a test for CDB_Something function, you'd add:
|
||||
- CDB_SomethingTest.sql
|
||||
- CDB_SomethingTest_expect
|
||||
|
||||
In case you need multiple expects of a test for different versions you have
|
||||
to add .pg$(VERSION) at the end of the file.
|
||||
|
||||
For example if you want an expect file for PG11 you need to have two expect files:
|
||||
|
||||
- CDB_SomethingTest_expect
|
||||
- CDB_SomethingTest_expect.pg11
|
||||
|
||||
To easy the generation of the expected file you can initially omit it,
|
||||
then run "make -C .. installcheck" from the top-level dir and copy
|
||||
../results/test/CDB_SomethingTest.out to CDB_SomethingTest_expect chopping
|
||||
|
||||
@@ -590,6 +590,68 @@ test_extension|public|"local-table-with-dashes"'
|
||||
sql postgres "DROP FOREIGN TABLE IF EXISTS test_fdw.cdb_tablemetadata;"
|
||||
sql postgres "SELECT cartodb.CDB_Get_Foreign_Updated_At('test_fdw.foo') IS NULL" should 't'
|
||||
|
||||
|
||||
# Check user-defined FDW's
|
||||
# Set up a user foreign server
|
||||
read -d '' ufdw_config <<- EOF
|
||||
{
|
||||
"server": {
|
||||
"extensions": "postgis",
|
||||
"dbname": "fdw_target",
|
||||
"host": "localhost",
|
||||
"port": ${PGPORT:-5432}
|
||||
},
|
||||
"user_mapping": {
|
||||
"user": "fdw_user",
|
||||
"password": "foobarino"
|
||||
}
|
||||
}
|
||||
EOF
|
||||
sql postgres "SELECT cartodb._CDB_SetUp_User_PG_FDW_Server('user-defined-test', '$ufdw_config');"
|
||||
|
||||
# Grant a user access to that FDW, and to grant to others
|
||||
sql postgres 'GRANT "cdb_fdw_user-defined-test" TO cdb_testmember_1 WITH ADMIN OPTION;'
|
||||
|
||||
# Set up a user foreign table
|
||||
sql cdb_testmember_1 "SELECT cartodb.CDB_SetUp_User_PG_FDW_Table('user-defined-test', 'test_fdw', 'foo');"
|
||||
|
||||
# Check that the table can be accessed by the owner/creator
|
||||
sql cdb_testmember_1 'SELECT * from "cdb_fdw_user-defined-test".foo;'
|
||||
sql cdb_testmember_1 'SELECT a from "cdb_fdw_user-defined-test".foo LIMIT 1;' should 42
|
||||
|
||||
# Check that a role with no permissions cannot use the FDW to access a remote table
|
||||
sql cdb_testmember_2 'IMPORT FOREIGN SCHEMA test_fdw LIMIT TO (foo) FROM SERVER "cdb_fdw_user-defined-test" INTO public' fails
|
||||
|
||||
# Check that the table can be accessed by some other user by granting the role
|
||||
sql cdb_testmember_2 'SELECT a from "cdb_fdw_user-defined-test".foo LIMIT 1;' fails
|
||||
sql cdb_testmember_1 'GRANT "cdb_fdw_user-defined-test" TO cdb_testmember_2;'
|
||||
sql cdb_testmember_2 'SELECT a from "cdb_fdw_user-defined-test".foo LIMIT 1;' should 42
|
||||
sql cdb_testmember_1 'REVOKE "cdb_fdw_user-defined-test" FROM cdb_testmember_2;'
|
||||
|
||||
# Check that the table can be accessed by org members
|
||||
sql cdb_testmember_2 'SELECT a from "cdb_fdw_user-defined-test".foo LIMIT 1;' fails
|
||||
sql cdb_testmember_1 "SELECT cartodb.CDB_Organization_Grant_Role('cdb_fdw_user-defined-test');"
|
||||
sql cdb_testmember_2 'SELECT a from "cdb_fdw_user-defined-test".foo LIMIT 1;' should 42
|
||||
sql cdb_testmember_1 "SELECT cartodb.CDB_Organization_Revoke_Role('cdb_fdw_user-defined-test');"
|
||||
|
||||
# By default publicuser cannot access the FDW
|
||||
sql publicuser 'SELECT a from "cdb_fdw_user-defined-test".foo LIMIT 1;' fails
|
||||
sql cdb_testmember_1 'GRANT "cdb_fdw_user-defined-test" TO publicuser;' # but can be granted
|
||||
sql publicuser 'SELECT a from "cdb_fdw_user-defined-test".foo LIMIT 1;' should 42
|
||||
sql cdb_testmember_1 'REVOKE "cdb_fdw_user-defined-test" FROM publicuser;'
|
||||
|
||||
# If there are dependent objects, we cannot drop the foreign server
|
||||
sql postgres "SELECT cartodb._CDB_Drop_User_PG_FDW_Server('user-defined-test')" fails
|
||||
sql cdb_testmember_1 'DROP FOREIGN TABLE "cdb_fdw_user-defined-test".foo;'
|
||||
sql postgres "SELECT cartodb._CDB_Drop_User_PG_FDW_Server('user-defined-test')"
|
||||
|
||||
# But if there are, we can set the force flag to true to drop everything (defaults to false)
|
||||
sql postgres "SELECT cartodb._CDB_SetUp_User_PG_FDW_Server('another_user_defined_test', '$ufdw_config');"
|
||||
sql postgres 'GRANT cdb_fdw_another_user_defined_test TO cdb_testmember_1 WITH ADMIN OPTION;'
|
||||
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;'
|
||||
|
||||
Reference in New Issue
Block a user