Compare commits

...

47 Commits

Author SHA1 Message Date
Raul Marin
b68ce72889 Release 0.31.0 2019-10-08 12:47:32 +02:00
Raúl Marín
7a23ea815c Merge pull request #371 from Algunenano/sec_definer
Sec definer
2019-10-08 12:32:26 +02:00
Raul Marin
2533d0996c Add NEWs 2019-10-03 18:59:01 +02:00
Raul Marin
048234cd80 CDB_Groups_API: Secure search_path 2019-10-03 18:58:27 +02:00
Raul Marin
5a12033609 Adapt tests to changes 2019-10-03 18:58:27 +02:00
Raul Marin
a580bedefc Set safe schema on some functions 2019-10-03 18:58:27 +02:00
Raul Marin
0e891eff7f Remove cartodb from search path
All calls to the extension functions should, and are,
be properly qualified, so there is no need to keep
the cartodb schema in the search_path
2019-10-03 18:58:27 +02:00
Raul Marin
52b3290d26 CDB_TableMetadata: Use secure search_path 2019-10-03 18:58:27 +02:00
Raul Marin
186ee37a57 CDB_Username: Set secure search_path 2019-10-03 18:58:27 +02:00
Raul Marin
0898881470 Oauth: Set secure search_path 2019-10-03 18:58:27 +02:00
Raul Marin
4dfd71639a CDB_OAuthReassignTableOwnerOnCreation: Use CDB_Conf_GetConf
Instead of accessing the cdb_conf table directly
2019-10-03 18:58:27 +02:00
Raul Marin
c6b90aac8a GhostTables: Set secure search_path 2019-10-03 18:58:27 +02:00
Raúl Marín
8a87f96f04 Merge pull request #370 from Algunenano/ghost_matview
Ghost tables: Add missing tags
2019-10-03 15:06:11 +02:00
Raul Marin
7c10fcc363 Update NEWS 2019-10-01 11:03:53 +02:00
Raul Marin
2f178bd89e _CDB_SetUp_User_PG_FDW_Server: Minor log changes 2019-10-01 11:02:34 +02:00
Raul Marin
32489c4eab Ghost tables: Add missing tags
- Add materialized views commands.
- Add missing alter trigger.
- Add 'IMPORT FOREIGN SCHEMA' since it might create new tables.
- Add 'DROP EXTENSION' and 'DROP TYPE' since they alter table columns.
- Add 'DROP SCHEMA' and 'DROP SERVER' as they drop tables.
2019-10-01 11:02:34 +02:00
Rafa de la Torre
afa52aa92b Prepare release 0.30.0 2019-07-17 09:58:21 +02:00
Rafa de la Torre
746dbea434 Merge pull request #369 from CartoDB/user-defined-fdw
User defined FDW's
2019-07-17 09:52:23 +02:00
Rafa de la Torre
f9bd469ea9 Make oauth tests a bit more robust 2019-07-17 09:46:49 +02:00
Rafa de la Torre
402d97daa6 Merge remote-tracking branch 'origin/master' into user-defined-fdw 2019-07-17 09:18:35 +02:00
Rafa de la Torre
e41d2ec019 Add a flag to force drop of user FDW and related objects
If force = true then it will add the subclause `CASCADE` to the SQL
DDL sentences that support it, otherwise it'll use `RESTRICT` which is
the default and exact opposite.
2019-07-16 17:40:05 +02:00
Rafa de la Torre
3c460f1a85 Add a bunch of RAISE NOTICE's to inform user about progress 2019-07-16 17:03:23 +02:00
Rafa de la Torre
076207c49c Make sure there are no (double)escaping issues 2019-07-16 16:24:02 +02:00
Rafa de la Torre
ce1e9ac41c Prefix all objects created with cdb_fdw_
Build the DB objects related to a user FDW with the following form:
`cdb_fdw_name`. This is aimed at easily inspect and filter them.

As requested in code review.
2019-07-16 15:35:35 +02:00
Rafa de la Torre
0f33ee8b22 Prepend an underscore (_) to functions meant to be run by superuser
_CDB_SetUp_User_PG_FDW_Server and _CDB_Drop_User_PG_FDW_Server are
meant to be executed by a superuser. Therefore they shouldn't be
considered part of the public API and hence the _CDB_Private_Function
naming convention.
2019-07-16 14:32:32 +02:00
Rafa de la Torre
a32dea0282 Remove SECURITY DEFINER from user-defined FDW's 2019-07-16 13:26:03 +02:00
Rafa de la Torre
3a255df9d0 Rename PG-FDW's-specific functions to _PG_FDW_
As per review comment.
2019-07-16 13:14:11 +02:00
Rafa de la Torre
c4e2549dc8 A few more permissions tests for completeness 2019-07-15 18:14:23 +02:00
Rafa de la Torre
2e9f642378 Check when users shall not have permissions to the FDW 2019-07-15 17:32:48 +02:00
Rafa de la Torre
99096d41e0 Drop the role when dropping a user-defined FDW 2019-07-15 17:25:48 +02:00
Rafa de la Torre
3a10ef7e76 Add ability to grant fdw role to org members 2019-07-15 16:54:23 +02:00
Rafa de la Torre
a20676f391 Add a test/example of granting the fdw role 2019-07-15 16:19:06 +02:00
Rafa de la Torre
37004db047 Add new function to drop a user-defined foreign server 2019-07-15 16:14:07 +02:00
Rafa de la Torre
1189d70b2a Request host auth to use password
This is required for non superusers to use FDW's. See
https://www.postgresql.org/docs/11/postgres-fdw.html#id-1.11.7.42.10
2019-07-15 14:52:39 +02:00
Rafa de la Torre
8cfc8e65cf Test with a regular user (non-superadmin) 2019-07-15 14:44:21 +02:00
Rafa de la Torre
6e34e16b8d Add basic test for user-defined FDW's 2019-07-15 13:16:14 +02:00
Rafa de la Torre
70220e04c1 Allow for imports of tables in different source schemas 2019-07-15 13:13:21 +02:00
Rafa de la Torre
d2d909145d Add convenience function to import fdw tables 2019-07-12 16:53:34 +02:00
Rafa de la Torre
34dec227c4 Rename to CDB_SetUp_User_Foreign_Server 2019-07-12 16:53:34 +02:00
Rafa de la Torre
99e92e2505 Create a "PUBLIC" user mapping 2019-07-12 16:53:34 +02:00
Rafa de la Torre
c58a084102 Tweak ownership of db objects 2019-07-12 16:53:34 +02:00
Rafa de la Torre
b7907ff82f Fix typo granting perms 2019-07-12 16:53:34 +02:00
Rafa de la Torre
12d955075a Fix bug iterating user_mapping options 2019-07-12 16:53:34 +02:00
Rafa de la Torre
10a4d85c01 Fix typo in example: missing closing } 2019-07-12 16:53:24 +02:00
Rafa de la Torre
524bb6ad42 Fix copy/paste typos 2019-07-12 12:49:59 +02:00
Rafa de la Torre
4da89d8abd First version of the function WIP 2019-07-12 12:40:02 +02:00
Rafa de la Torre
c7311ba48e A stub of a convenient FDW function 2019-07-12 12:00:30 +02:00
15 changed files with 391 additions and 30 deletions

View File

@@ -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:

View File

@@ -1,7 +1,7 @@
# cartodb/Makefile
EXTENSION = cartodb
EXTVERSION = 0.29.0
EXTVERSION = 0.31.0
SED = sed
AWK = awk
@@ -102,6 +102,8 @@ UPGRADABLE = \
0.28.0 \
0.28.1 \
0.29.0 \
0.30.0 \
0.31.0 \
$(EXTVERSION)dev \
$(EXTVERSION)next \
$(END)

View File

@@ -1,3 +1,10 @@
0.31.0 (2019-10-08)
* Ghost tables: Add missing tags (#370)
* Set search_path in security definer functions.
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

View File

@@ -6,8 +6,11 @@ $$
BEGIN
RETURN @extschema@.CDB_Conf_GetConf('analysis_quota_factor')::text::float8;
END;
$$
LANGUAGE 'plpgsql' STABLE PARALLEL SAFE SECURITY DEFINER;
$$ LANGUAGE 'plpgsql'
STABLE
PARALLEL SAFE
SECURITY DEFINER
SET search_path = pg_temp;
-- Get the factor (fraction of the quota) for Camshaft cached analysis tables

View File

@@ -12,7 +12,12 @@ BEGIN
EXECUTE Format('ANALYZE %s;', reloid);
END IF;
END
$$ LANGUAGE 'plpgsql' VOLATILE STRICT PARALLEL UNSAFE SECURITY DEFINER;
$$ LANGUAGE 'plpgsql'
VOLATILE
STRICT
PARALLEL UNSAFE
SECURITY DEFINER
SET search_path = pg_temp;
-- Return a row count estimate of the result of a query using statistics
CREATE OR REPLACE FUNCTION @extschema@.CDB_EstimateRowCount(query text)

View File

@@ -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((

View File

@@ -63,7 +63,11 @@ AS $$
PERFORM @extschema@._CDB_LinkGhostTables(username, db_name, event_name);
RAISE NOTICE '_CDB_LinkGhostTables() called with username=%, event_name=%', username, event_name;
END;
$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE SECURITY DEFINER;
$$ LANGUAGE plpgsql
VOLATILE
PARALLEL UNSAFE
SECURITY DEFINER
SET search_path = pg_temp;
-- Trigger function to call CDB_LinkGhostTables()
CREATE OR REPLACE FUNCTION @extschema@._CDB_LinkGhostTablesTrigger()
@@ -76,7 +80,11 @@ AS $$
PERFORM @extschema@.CDB_LinkGhostTables(ddl_tag);
RETURN NULL;
END;
$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE SECURITY DEFINER;
$$ LANGUAGE plpgsql
VOLATILE
PARALLEL UNSAFE
SECURITY DEFINER
SET search_path = pg_temp;
-- Event trigger to save the current transaction in @extschema@.cdb_ddl_execution
CREATE OR REPLACE FUNCTION @extschema@.CDB_SaveDDLTransaction()
@@ -85,7 +93,11 @@ AS $$
BEGIN
INSERT INTO @extschema@.cdb_ddl_execution VALUES (txid_current(), tg_tag) ON CONFLICT ON CONSTRAINT cdb_ddl_execution_pkey DO NOTHING;
END;
$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE SECURITY DEFINER;
$$ LANGUAGE plpgsql
VOLATILE
PARALLEL UNSAFE
SECURITY DEFINER
SET search_path = pg_temp;
-- Creates the trigger on DDL events to link ghost tables
CREATE OR REPLACE FUNCTION @extschema@.CDB_EnableGhostTablesTrigger()
@@ -106,7 +118,33 @@ AS $$
CREATE EVENT TRIGGER link_ghost_tables
ON ddl_command_end
WHEN TAG IN ('CREATE TABLE', 'SELECT INTO', 'DROP TABLE', 'ALTER TABLE', 'CREATE TRIGGER', 'DROP TRIGGER', 'CREATE VIEW', 'DROP VIEW', 'ALTER VIEW', 'CREATE FOREIGN TABLE', 'ALTER FOREIGN TABLE', 'DROP FOREIGN TABLE')
WHEN TAG IN ('CREATE TABLE',
'SELECT INTO',
'DROP TABLE',
'ALTER TABLE',
'CREATE TRIGGER',
'DROP TRIGGER',
'ALTER TRIGGER',
'CREATE VIEW',
'DROP VIEW',
'ALTER VIEW',
'CREATE FOREIGN TABLE',
'ALTER FOREIGN TABLE',
'DROP FOREIGN TABLE',
'ALTER MATERIALIZED VIEW',
'CREATE MATERIALIZED VIEW',
'DROP MATERIALIZED VIEW',
'IMPORT FOREIGN SCHEMA',
'DROP EXTENSION',
'DROP SCHEMA',
'DROP SERVER',
'DROP TYPE')
EXECUTE PROCEDURE @extschema@.CDB_SaveDDLTransaction();
END;
$$ LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE;

View File

@@ -22,7 +22,11 @@ $$
body = '{ "name": "%s", "database_role": "%s" }' % (group_name, group_role)
query = "select @extschema@._CDB_Group_API_Request('POST', '%s', '%s', '{200, 409}') as response_status" % (url, body)
plpy.execute(query)
$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE SECURITY DEFINER;
$$ LANGUAGE 'plpythonu'
VOLATILE
PARALLEL UNSAFE
SECURITY DEFINER
SET search_path = pg_temp;
CREATE OR REPLACE
FUNCTION @extschema@._CDB_Group_DropGroup_API(group_name text)
@@ -35,7 +39,11 @@ $$
query = "select @extschema@._CDB_Group_API_Request('DELETE', '%s', '', '{204, 404}') as response_status" % url
plpy.execute(query)
$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE SECURITY DEFINER;
$$ LANGUAGE 'plpythonu'
VOLATILE
PARALLEL UNSAFE
SECURITY DEFINER
SET search_path = pg_temp;
CREATE OR REPLACE
FUNCTION @extschema@._CDB_Group_RenameGroup_API(old_group_name text, new_group_name text, new_group_role text)
@@ -48,7 +56,11 @@ $$
body = '{ "name": "%s", "database_role": "%s" }' % (new_group_name, new_group_role)
query = "select @extschema@._CDB_Group_API_Request('PUT', '%s', '%s', '{200, 409}') as response_status" % (url, body)
plpy.execute(query)
$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE SECURITY DEFINER;
$$ LANGUAGE 'plpythonu'
VOLATILE
PARALLEL UNSAFE
SECURITY DEFINER
SET search_path = pg_temp;
CREATE OR REPLACE
FUNCTION @extschema@._CDB_Group_AddUsers_API(group_name text, usernames text[])
@@ -61,7 +73,11 @@ $$
body = "{ \"users\": [\"%s\"] }" % "\",\"".join(usernames)
query = "select @extschema@._CDB_Group_API_Request('POST', '%s', '%s', '{200, 409}') as response_status" % (url, body)
plpy.execute(query)
$$ LANGUAGE 'plpythonu' VOLATILE SECURITY DEFINER;
$$ LANGUAGE 'plpythonu'
VOLATILE
PARALLEL UNSAFE
SECURITY DEFINER
SET search_path = pg_temp;
CREATE OR REPLACE
FUNCTION @extschema@._CDB_Group_RemoveUsers_API(group_name text, usernames text[])
@@ -74,7 +90,11 @@ $$
body = "{ \"users\": [\"%s\"] }" % "\",\"".join(usernames)
query = "select @extschema@._CDB_Group_API_Request('DELETE', '%s', '%s', '{200, 404}') as response_status" % (url, body)
plpy.execute(query)
$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE SECURITY DEFINER;
$$ LANGUAGE 'plpythonu'
VOLATILE
PARALLEL UNSAFE
SECURITY DEFINER
SET search_path = pg_temp;
DO LANGUAGE 'plpgsql' $$
BEGIN
@@ -95,7 +115,11 @@ $$
body = '{ "access": "%s" }' % access
query = "select @extschema@._CDB_Group_API_Request('PUT', '%s', '%s', '{200, 409}') as response_status" % (url, body)
plpy.execute(query)
$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE SECURITY DEFINER;
$$ LANGUAGE 'plpythonu'
VOLATILE
PARALLEL UNSAFE
SECURITY DEFINER
SET search_path = pg_temp;
DO LANGUAGE 'plpgsql' $$
BEGIN
@@ -115,7 +139,11 @@ $$
url = '/api/v1/databases/{0}/groups/%s/permission/%s/tables/%s' % (urllib.pathname2url(group_name), username, table_name)
query = "select @extschema@._CDB_Group_API_Request('DELETE', '%s', '', '{200, 404}') as response_status" % url
plpy.execute(query)
$$ LANGUAGE 'plpythonu' VOLATILE PARALLEL UNSAFE SECURITY DEFINER;
$$ LANGUAGE 'plpythonu'
VOLATILE
PARALLEL UNSAFE
SECURITY DEFINER
SET search_path = pg_temp;
DO LANGUAGE 'plpgsql' $$
BEGIN

View File

@@ -1,7 +1,6 @@
-- 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;
@@ -17,17 +16,21 @@ BEGIN
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;
SELECT value->>'ownership_role_name' from @extschema@.CDB_Conf_GetConf('api_keys_' || quote_ident(creator_role)) value 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 '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;
$$ LANGUAGE plpgsql
VOLATILE
PARALLEL UNSAFE
SECURITY DEFINER
SET search_path = pg_temp;
-- Creates the trigger on DDL events in order to reassign the owner
CREATE OR REPLACE FUNCTION @extschema@.CDB_EnableOAuthReassignTablesTrigger()

View File

@@ -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;

View File

@@ -318,7 +318,7 @@ $$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE;
-- This function is declared SECURITY DEFINER so it executes with the privileges
-- of the function creator to have a chance to alter the privileges of the
-- overview table to match those of the dataset. It will only perform any change
-- if the overview table belgons to the same scheme as the dataset and it
-- if the overview table belongs to the same scheme as the dataset and it
-- matches the scheme naming for overview tables.
CREATE OR REPLACE FUNCTION @extschema@._CDB_Register_Overview(dataset REGCLASS, overview_table REGCLASS, overview_z INTEGER)
RETURNS VOID
@@ -362,7 +362,11 @@ AS $$
-- it should be done here (CDB_Overviews would consume such metadata)
END IF;
END
$$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE SECURITY DEFINER;
$$ LANGUAGE PLPGSQL
VOLATILE
PARALLEL UNSAFE
SECURITY DEFINER
SET search_path = pg_temp;
-- Dataset attributes (column names other than the
-- CartoDB primary key and geometry columns) which should be aggregated

View File

@@ -43,7 +43,7 @@ BEGIN
);
WITH nv as (
SELECT TG_RELID as tabname, NOW() as t
SELECT TG_RELID as tabname, now() as t
), updated as (
UPDATE @extschema@.CDB_TableMetadata x SET updated_at = nv.t
FROM nv WHERE x.tabname = nv.tabname
@@ -55,8 +55,11 @@ BEGIN
RETURN NULL;
END;
$$
LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE SECURITY DEFINER;
$$ LANGUAGE plpgsql
VOLATILE
PARALLEL UNSAFE
SECURITY DEFINER
SET search_path = pg_temp;
--
-- Trigger invalidating varnish whenever CDB_TableMetadata
@@ -116,8 +119,11 @@ BEGIN
RETURN NULL;
END;
$$
LANGUAGE plpgsql VOLATILE PARALLEL UNSAFE SECURITY DEFINER;
$$ LANGUAGE plpgsql
VOLATILE
PARALLEL UNSAFE
SECURITY DEFINER
SET search_path = pg_temp;
DROP TRIGGER IF EXISTS table_modified ON @extschema@.CDB_TableMetadata;
-- NOTE: on DELETE we would be unable to convert the table

View File

@@ -2,5 +2,9 @@
CREATE OR REPLACE FUNCTION @extschema@.CDB_Username()
RETURNS text
AS $$
SELECT @extschema@.CDB_Conf_GetConf(CONCAT('api_keys_', session_user))->>'username';
$$ LANGUAGE SQL STABLE PARALLEL SAFE SECURITY DEFINER;
SELECT @extschema@.CDB_Conf_GetConf(concat('api_keys_', session_user))->>'username';
$$ LANGUAGE SQL
STABLE
PARALLEL SAFE
SECURITY DEFINER
SET search_path = pg_temp;

View File

@@ -1,7 +1,9 @@
-- 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":[]}');

View File

@@ -362,7 +362,7 @@ function test_cdb_tablemetadatatouch_fails_from_user_without_permission() {
function test_cdb_tablemetadatatouch_fully_qualifies_names() {
sql postgres "CREATE TABLE touch_invalidations (table_name text);"
sql postgres "create or replace function cartodb.cdb_invalidate_varnish(table_name text) returns void as \$\$ begin insert into touch_invalidations select table_name; end; \$\$ language 'plpgsql';"
sql postgres "create or replace function cartodb.cdb_invalidate_varnish(table_name text) returns void as \$\$ begin insert into public.touch_invalidations select table_name; end; \$\$ language 'plpgsql';"
#default schema
sql "CREATE TABLE touch_example (a int);"
@@ -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;'