Merge pull request #367 from CartoDB/oauth_create_table_trigger

Oauth create table trigger
This commit is contained in:
Gonzalo Riestra 2019-07-15 13:43:08 +02:00 committed by GitHub
commit 32db4fd81e
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
8 changed files with 432 additions and 2 deletions

View File

@ -1,7 +1,7 @@
# cartodb/Makefile # cartodb/Makefile
EXTENSION = cartodb EXTENSION = cartodb
EXTVERSION = 0.28.1 EXTVERSION = 0.29.0
SED = sed SED = sed
AWK = awk AWK = awk
@ -101,6 +101,7 @@ UPGRADABLE = \
0.27.2 \ 0.27.2 \
0.28.0 \ 0.28.0 \
0.28.1 \ 0.28.1 \
0.29.0 \
$(EXTVERSION)dev \ $(EXTVERSION)dev \
$(EXTVERSION)next \ $(EXTVERSION)next \
$(END) $(END)
@ -130,6 +131,8 @@ PG_CONFIG = pg_config
PGXS := $(shell $(PG_CONFIG) --pgxs) PGXS := $(shell $(PG_CONFIG) --pgxs)
include $(PGXS) include $(PGXS)
PG_VERSION := $(shell $(PG_CONFIG) --version | $(AWK) '{split($$2,a,"."); print a[1]}')
$(EXTENSION)--$(EXTVERSION).sql: $(CDBSCRIPTS) cartodb_version.sql Makefile $(EXTENSION)--$(EXTVERSION).sql: $(CDBSCRIPTS) cartodb_version.sql Makefile
echo '\echo Use "CREATE EXTENSION $(EXTENSION)" to load this file. \quit' > $@ echo '\echo Use "CREATE EXTENSION $(EXTENSION)" to load this file. \quit' > $@
cat $(CDBSCRIPTS) | \ cat $(CDBSCRIPTS) | \
@ -171,7 +174,11 @@ legacy_regress: $(REGRESS_OLD) Makefile
$(SED) -e 's/@@VERSION@@/$(EXTVERSION)/' -e 's/@extschema@/cartodb/g' -e "s/@postgisschema@/public/g" >> $${of}; \ $(SED) -e 's/@@VERSION@@/$(EXTVERSION)/' -e 's/@extschema@/cartodb/g' -e "s/@postgisschema@/public/g" >> $${of}; \
exp=expected/test/$${tn}.out; \ exp=expected/test/$${tn}.out; \
echo '\set ECHO none' > $${exp}; \ 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 done
test_organization: test_organization:

View File

@ -1,3 +1,9 @@
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) 0.28.1 (2019-07-04)
* Avoid temporary tables creation in CDB_SyncTable (#366) * Avoid temporary tables creation in CDB_SyncTable (#366)
* Make CDB_Get_Foreign_Updated_At robust to missing CDB_TableMetadata (#362) * Make CDB_Get_Foreign_Updated_At robust to missing CDB_TableMetadata (#362)

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

View File

@ -0,0 +1 @@
../scripts-available/CDB_OAuth.sql

175
test/CDB_OAuth.sql Normal file
View File

@ -0,0 +1,175 @@
-- Create user and enable OAuth event trigger
\set QUIET on
SET client_min_messages TO error;
CREATE ROLE "creator_role" LOGIN;
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
View 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

View 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

View File

@ -6,6 +6,14 @@ Example, to add a test for CDB_Something function, you'd add:
- CDB_SomethingTest.sql - CDB_SomethingTest.sql
- CDB_SomethingTest_expect - 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, 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 then run "make -C .. installcheck" from the top-level dir and copy
../results/test/CDB_SomethingTest.out to CDB_SomethingTest_expect chopping ../results/test/CDB_SomethingTest.out to CDB_SomethingTest_expect chopping