diff --git a/scripts-available/CDB_Organizations.sql b/scripts-available/CDB_Organizations.sql index 9af6081..a103d75 100644 --- a/scripts-available/CDB_Organizations.sql +++ b/scripts-available/CDB_Organizations.sql @@ -108,10 +108,31 @@ CREATE OR REPLACE FUNCTION cartodb.CDB_Organization_Add_Table_Read_Write_Permission(from_schema text, table_name text, to_role_name text) RETURNS void AS $$ +DECLARE + sequence_names TEXT[]; + sequence_name TEXT; BEGIN EXECUTE 'GRANT USAGE ON SCHEMA "' || from_schema || '" TO "' || to_role_name || '"'; EXECUTE 'GRANT SELECT, INSERT, UPDATE, DELETE ON "' || from_schema || '"."' || table_name || '" TO "' || to_role_name || '"'; - EXECUTE 'GRANT USAGE, SELECT ON SEQUENCE ' || pg_catalog.pg_get_serial_sequence(Format('%I.%I', from_schema, table_name), 'cartodb_id') || ' TO "' || to_role_name || '"'; + + EXECUTE 'SELECT + array_agg(n.nspname || ''.'' || c.relname) + FROM + pg_depend d + JOIN pg_class c ON d.objid = c.oid + JOIN pg_namespace n ON c.relnamespace = n.oid + WHERE + d.refobjsubid > 0 AND + d.classid = ''pg_class''::regclass AND + c.relkind = ''S''::"char" AND + d.refobjid = (''' || from_schema || '.' || table_name ||''')::regclass' + INTO sequence_names; + + IF sequence_names IS NOT NULL THEN + FOREACH sequence_name IN ARRAY sequence_names LOOP + EXECUTE 'GRANT USAGE, SELECT ON SEQUENCE ' || sequence_name || ' TO "' || to_role_name || '"'; + END LOOP; + END IF; END $$ LANGUAGE PLPGSQL VOLATILE PARALLEL UNSAFE;