fix oauth reassign ownership for functions
This commit is contained in:
parent
415220777e
commit
11b30c8f59
@ -15,13 +15,18 @@ BEGIN
|
||||
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;
|
||||
IF obj.object_type = 'function' THEN
|
||||
SELECT rolname FROM pg_proc JOIN pg_roles ON proowner = pg_roles.oid WHERE pg_proc.oid = obj.objid INTO creator_role;
|
||||
ELSE
|
||||
SELECT rolname FROM pg_class JOIN pg_roles ON relowner = pg_roles.oid WHERE pg_class.oid = obj.objid INTO creator_role;
|
||||
END IF;
|
||||
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
|
||||
RAISE DEBUG 'owner_role not found';
|
||||
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);
|
||||
EXECUTE 'GRANT ALL ON ' || obj.object_type || ' ' || obj.object_identity || ' TO ' || QUOTE_IDENT(creator_role);
|
||||
RAISE DEBUG 'Changing ownership from % to %', creator_role, owner_role;
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
@ -36,12 +36,14 @@ 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;
|
||||
CREATE FUNCTION test_function() RETURNS text AS $$ BEGIN RETURN 'test'; END; $$ LANGUAGE PLPGSQL;
|
||||
|
||||
SELECT * FROM test;
|
||||
SELECT * FROM test_tablesas;
|
||||
SELECT * FROM test_view;
|
||||
SELECT * FROM test_mview;
|
||||
SELECT * FROM test_selectinto;
|
||||
SELECT test_function();
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION "ownership_role";
|
||||
@ -52,6 +54,7 @@ SELECT 'denied_tableas', catch_permission_error($$SELECT * FROM test_tablesas;$$
|
||||
SELECT 'denied_view', catch_permission_error($$SELECT * FROM test_view;$$);
|
||||
SELECT 'denied_mview', catch_permission_error($$SELECT * FROM test_mview;$$);
|
||||
SELECT 'denied_selectinto', catch_permission_error($$SELECT * FROM test_selectinto;$$);
|
||||
SELECT test_function();
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION "creator_role";
|
||||
@ -62,6 +65,7 @@ DROP VIEW test_view;
|
||||
DROP MATERIALIZED VIEW test_mview;
|
||||
DROP TABLE test_selectinto;
|
||||
DROP TABLE test;
|
||||
DROP FUNCTION test_function;
|
||||
|
||||
-- Second part with event trigger but without ownership_role_name in cdb_conf
|
||||
|
||||
@ -77,12 +81,14 @@ 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;
|
||||
CREATE FUNCTION test2_function() RETURNS text AS $$ BEGIN RETURN 'test'; END; $$ LANGUAGE PLPGSQL;
|
||||
|
||||
SELECT * FROM test2;
|
||||
SELECT * FROM test2_tablesas;
|
||||
SELECT * FROM test2_view;
|
||||
SELECT * FROM test2_mview;
|
||||
SELECT * FROM test2_selectinto;
|
||||
SELECT test2_function();
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION "ownership_role";
|
||||
@ -93,6 +99,7 @@ SELECT 'denied_tableas2', catch_permission_error($$SELECT * FROM test2_tablesas;
|
||||
SELECT 'denied_view2', catch_permission_error($$SELECT * FROM test2_view;$$);
|
||||
SELECT 'denied_mview2', catch_permission_error($$SELECT * FROM test2_mview;$$);
|
||||
SELECT 'denied_selectinto2', catch_permission_error($$SELECT * FROM test2_selectinto;$$);
|
||||
SELECT test2_function();
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION "creator_role";
|
||||
@ -103,6 +110,7 @@ DROP VIEW test2_view;
|
||||
DROP MATERIALIZED VIEW test2_mview;
|
||||
DROP TABLE test2_selectinto;
|
||||
DROP TABLE test2;
|
||||
DROP FUNCTION test2_function;
|
||||
|
||||
-- Third part with event trigger but with empty ownership_role_name in cdb_conf
|
||||
|
||||
@ -118,12 +126,14 @@ 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;
|
||||
CREATE FUNCTION test3_function() RETURNS text AS $$ BEGIN RETURN 'test'; END; $$ LANGUAGE PLPGSQL;
|
||||
|
||||
SELECT * FROM test3;
|
||||
SELECT * FROM test3_tablesas;
|
||||
SELECT * FROM test3_view;
|
||||
SELECT * FROM test3_mview;
|
||||
SELECT * FROM test3_selectinto;
|
||||
SELECT test_function();
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION "ownership_role";
|
||||
@ -134,6 +144,7 @@ SELECT 'denied_tableas3', catch_permission_error($$SELECT * FROM test3_tablesas;
|
||||
SELECT 'denied_view3', catch_permission_error($$SELECT * FROM test3_view;$$);
|
||||
SELECT 'denied_mview3', catch_permission_error($$SELECT * FROM test3_mview;$$);
|
||||
SELECT 'denied_selectinto3', catch_permission_error($$SELECT * FROM test3_selectinto;$$);
|
||||
SELECT test_function();
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION "creator_role";
|
||||
@ -144,6 +155,7 @@ DROP VIEW test3_view;
|
||||
DROP MATERIALIZED VIEW test3_mview;
|
||||
DROP TABLE test3_selectinto;
|
||||
DROP TABLE test3;
|
||||
DROP FUNCTION test3_function;
|
||||
|
||||
-- Fourth part with the event trigger active and configured
|
||||
|
||||
@ -159,12 +171,14 @@ 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;
|
||||
CREATE FUNCTION test4_function() RETURNS text AS $$ BEGIN RETURN 'test'; END; $$ LANGUAGE PLPGSQL;
|
||||
|
||||
SELECT * FROM test4;
|
||||
SELECT * FROM test4_tablesas;
|
||||
SELECT * FROM test4_view;
|
||||
SELECT * FROM test4_mview;
|
||||
SELECT * FROM test4_selectinto;
|
||||
SELECT test4_function();
|
||||
|
||||
\set QUIET on
|
||||
SET SESSION AUTHORIZATION "ownership_role";
|
||||
@ -175,6 +189,7 @@ SELECT * FROM test4_tablesas;
|
||||
SELECT * FROM test4_view;
|
||||
SELECT * FROM test4_mview;
|
||||
SELECT * FROM test4_selectinto;
|
||||
SELECT test4_function();
|
||||
|
||||
-- Ownership role drops the tables
|
||||
DROP TABLE test4_tablesas;
|
||||
@ -182,6 +197,7 @@ DROP VIEW test4_view;
|
||||
DROP MATERIALIZED VIEW test4_mview;
|
||||
DROP TABLE test4_selectinto;
|
||||
DROP TABLE test4;
|
||||
DROP FUNCTION test4_function;
|
||||
|
||||
-- Cleanup
|
||||
\set QUIET on
|
||||
|
Loading…
Reference in New Issue
Block a user