cartodb-postgresql/scripts-available/CDB_Groups.sql

154 lines
5.5 KiB
MySQL
Raw Normal View History

-- Creates a new group
CREATE OR REPLACE
FUNCTION cartodb.CDB_Group_CreateGroup(group_name text)
RETURNS VOID AS $$
DECLARE
group_role TEXT;
BEGIN
group_role := cartodb._CDB_Group_GroupRole(group_name);
2015-08-14 21:22:00 +08:00
EXECUTE format('CREATE ROLE "%s" NOLOGIN;', group_role);
PERFORM cartodb._CDB_Group_CreateGroup_API(current_database(), group_name, group_role);
END
$$ LANGUAGE PLPGSQL VOLATILE;
2015-08-10 19:40:59 +08:00
-- Drops group and everything that role owns
-- TODO: LIMITATION: in order to drop a role all its owned objects must be dropped before.
-- Right now this is done with DROP OWNED, which can only be done by a superadmin.
-- Not even the role creator can drop the role and the objects it owns.
-- All group owned objects by the group are permissions.
CREATE OR REPLACE
FUNCTION cartodb.CDB_Group_DropGroup(group_name text)
RETURNS VOID AS $$
DECLARE
2015-08-14 21:22:00 +08:00
group_role TEXT;
BEGIN
2015-08-14 21:22:00 +08:00
group_role := cartodb._CDB_Group_GroupRole(group_name);
EXECUTE format('DROP OWNED BY "%s"', group_role);
EXECUTE format('DROP ROLE IF EXISTS "%s"', group_role);
PERFORM cartodb._CDB_Group_DropGroup_API(current_database(), group_name);
END
$$ LANGUAGE PLPGSQL VOLATILE;
2015-08-10 17:21:57 +08:00
2015-08-10 19:46:35 +08:00
-- Renames a group
2015-08-10 17:21:57 +08:00
CREATE OR REPLACE
FUNCTION cartodb.CDB_Group_RenameGroup(old_group_name text, new_group_name text)
RETURNS VOID AS $$
BEGIN
2015-08-14 21:22:00 +08:00
EXECUTE format('ALTER ROLE "%s" RENAME TO "%s"', cartodb._CDB_Group_GroupRole(old_group_name), cartodb._CDB_Group_GroupRole(new_group_name));
2015-08-10 17:21:57 +08:00
END
$$ LANGUAGE PLPGSQL VOLATILE;
2015-08-10 17:21:57 +08:00
2015-08-10 19:46:35 +08:00
-- Adds a user to a group
2015-08-10 19:40:59 +08:00
CREATE OR REPLACE
FUNCTION cartodb.CDB_Group_AddMember(group_name text, username text)
RETURNS VOID AS $$
DECLARE
2015-08-11 20:08:55 +08:00
cdb_group_role TEXT;
cdb_user_role TEXT;
2015-08-10 19:40:59 +08:00
BEGIN
2015-08-11 20:08:55 +08:00
cdb_group_role := cartodb._CDB_Group_GroupRole(group_name);
cdb_user_role := cartodb._CDB_User_RoleFromUsername(username);
2015-08-14 21:22:00 +08:00
EXECUTE format('GRANT "%s" TO "%s"', cdb_group_role, cdb_user_role);
2015-08-10 19:40:59 +08:00
END
$$ LANGUAGE PLPGSQL VOLATILE;
2015-08-10 19:40:59 +08:00
2015-08-10 19:46:35 +08:00
-- Removes a user from a group
2015-08-10 19:40:59 +08:00
CREATE OR REPLACE
FUNCTION cartodb.CDB_Group_RemoveMember(group_name text, username text)
RETURNS VOID AS $$
DECLARE
2015-08-11 20:08:55 +08:00
cdb_group_role TEXT;
cdb_user_role TEXT;
2015-08-10 19:40:59 +08:00
BEGIN
2015-08-11 20:08:55 +08:00
cdb_group_role := cartodb._CDB_Group_GroupRole(group_name);
cdb_user_role := cartodb._CDB_User_RoleFromUsername(username);
2015-08-14 21:22:00 +08:00
EXECUTE format('REVOKE "%s" FROM "%s"', cdb_group_role, cdb_user_role);
2015-08-10 19:40:59 +08:00
END
$$ LANGUAGE PLPGSQL VOLATILE;
2015-08-10 19:40:59 +08:00
2015-08-10 19:46:35 +08:00
-- Grants table read permission to a group
2015-08-10 19:40:59 +08:00
CREATE OR REPLACE
FUNCTION cartodb.CDB_Group_Table_GrantRead(group_name text, username text, table_name text)
RETURNS VOID AS $$
DECLARE
cdb_group_role TEXT;
BEGIN
2015-08-10 19:42:27 +08:00
cdb_group_role := cartodb._CDB_Group_GroupRole(group_name);
2015-08-14 21:22:00 +08:00
EXECUTE format('GRANT USAGE ON SCHEMA "%s" TO "%s"', username, cdb_group_role);
EXECUTE format('GRANT SELECT ON TABLE "%s"."%s" TO "%s"', username, table_name, cdb_group_role );
2015-08-10 19:40:59 +08:00
END
$$ LANGUAGE PLPGSQL VOLATILE;
2015-08-10 19:40:59 +08:00
2015-08-10 19:53:57 +08:00
-- Grants table write permission to a group
CREATE OR REPLACE
FUNCTION cartodb.CDB_Group_Table_GrantReadWrite(group_name text, username text, table_name text)
RETURNS VOID AS $$
DECLARE
cdb_group_role TEXT;
BEGIN
cdb_group_role := cartodb._CDB_Group_GroupRole(group_name);
2015-08-14 21:22:00 +08:00
EXECUTE format('GRANT USAGE ON SCHEMA "%s" TO "%s"', username, cdb_group_role);
EXECUTE format('GRANT SELECT, INSERT, UPDATE, DELETE ON TABLE "%s"."%s" TO "%s"', username, table_name, cdb_group_role);
2015-08-10 19:53:57 +08:00
END
$$ LANGUAGE PLPGSQL VOLATILE;
2015-08-10 19:53:57 +08:00
2015-08-10 19:46:35 +08:00
-- Revokes all permissions on a table from a group
2015-08-10 19:40:59 +08:00
CREATE OR REPLACE
FUNCTION cartodb.CDB_Group_Table_RevokeAll(group_name text, username text, table_name text)
RETURNS VOID AS $$
DECLARE
cdb_group_role TEXT;
BEGIN
2015-08-10 19:42:27 +08:00
cdb_group_role := cartodb._CDB_Group_GroupRole(group_name);
2015-08-14 21:22:00 +08:00
EXECUTE format('REVOKE ALL ON TABLE "%s"."%s" FROM "%s"', username, table_name, cdb_group_role);
2015-08-10 19:40:59 +08:00
END
$$ LANGUAGE PLPGSQL VOLATILE;
2015-08-10 19:40:59 +08:00
2015-08-10 17:21:57 +08:00
-----------------------
-- Private functions
-----------------------
-- Given a group name returns a role. group_name must be a valid PostgreSQL idenfifier. See http://www.postgresql.org/docs/9.2/static/sql-syntax-lexical.html#SQL-SYNTAX-IDENTIFIERS
2015-08-10 17:21:57 +08:00
CREATE OR REPLACE
2015-08-10 19:42:27 +08:00
FUNCTION cartodb._CDB_Group_GroupRole(group_name text)
2015-08-10 17:21:57 +08:00
RETURNS TEXT AS $$
DECLARE
group_role TEXT;
prefix TEXT;
max_length constant INTEGER := 63;
2015-08-10 17:21:57 +08:00
BEGIN
2015-08-14 21:22:00 +08:00
prefix = format('%s_g_', cartodb._CDB_Group_ShortDatabaseName());
group_role := format('%s%s', prefix, group_name);
IF LENGTH(group_role) > max_length
THEN
RAISE EXCEPTION 'Group name must be shorter. It can''t have more than % characters, but it is longer (%): %', max_length - LENGTH(prefix), length(group_name), group_name;
END IF;
RETURN group_role;
2015-08-10 17:21:57 +08:00
END
$$ LANGUAGE PLPGSQL IMMUTABLE;
2015-08-10 19:40:59 +08:00
-- Returns the first owner of the schema matching username. Organization user schemas must have one only owner.
CREATE OR REPLACE
2015-08-10 19:42:27 +08:00
FUNCTION cartodb._CDB_User_RoleFromUsername(username text)
2015-08-10 19:40:59 +08:00
RETURNS TEXT AS $$
DECLARE
2015-08-11 20:08:55 +08:00
user_role TEXT;
2015-08-10 19:40:59 +08:00
BEGIN
-- This was preferred, but non-superadmins won't get results
--EXECUTE 'SELECT SCHEMA_OWNER FROM INFORMATION_SCHEMA.SCHEMATA WHERE SCHEMA_NAME = $1 LIMIT 1' INTO user_role USING username;
EXECUTE 'SELECT pg_get_userbyid(nspowner) FROM pg_namespace WHERE nspname = $1;' INTO user_role USING username;
2015-08-11 20:08:55 +08:00
RETURN user_role;
2015-08-10 19:40:59 +08:00
END
$$ LANGUAGE PLPGSQL IMMUTABLE;
-- Database names are too long, we need a shorter version for composing role names
CREATE OR REPLACE
FUNCTION cartodb._CDB_Group_ShortDatabaseName()
RETURNS TEXT AS $$
DECLARE
short_database_name TEXT;
BEGIN
EXECUTE 'SELECT md5(current_database())' INTO short_database_name;
RETURN short_database_name;
END
$$ LANGUAGE PLPGSQL IMMUTABLE;