summaryrefslogtreecommitdiff
path: root/sql/modules/admin.sql
blob: dfd702c8cd2900808530bf2e8b6fc2420850bf63 (plain)
  1. begin;
  2. create table lsmb_roles (
  3. user_id integer not null references users,
  4. role text not null
  5. );
  6. CREATE OR REPLACE FUNCTION admin_add_user_to_role(in_user TEXT, in_role TEXT) returns INT AS $$
  7. declare
  8. stmt TEXT;
  9. a_role name;
  10. a_user name;
  11. BEGIN
  12. -- Issue the grant
  13. select rolname into a_role from pg_roles where rolname = in_role;
  14. IF NOT FOUND THEN
  15. RAISE EXCEPTION 'Cannot grant permissions of a non-existant role.';
  16. END IF;
  17. select rolname into a_user from pg_roles where rolname = in_user;
  18. IF NOT FOUND THEN
  19. RAISE EXCEPTION 'Cannot grant permissions to a non-existant user.';
  20. END IF;
  21. stmt := 'GRANT '|| quote_ident(in_role) ||' to '|| quote_ident(in_user);
  22. EXECUTE stmt;
  23. return 1;
  24. END;
  25. $$ language 'plpgsql';
  26. CREATE OR REPLACE FUNCTION admin_remove_user_from_role(in_user TEXT, in_role TEXT) returns INT AS $$
  27. declare
  28. stmt TEXT;
  29. a_role name;
  30. a_user name;
  31. BEGIN
  32. -- Issue the grant
  33. select rolname into a_role from pg_roles where rolname = in_role;
  34. IF NOT FOUND THEN
  35. RAISE EXCEPTION 'Cannot revoke permissions of a non-existant role.';
  36. END IF;
  37. select rolname into a_user from pg_roles where rolname = in_user;
  38. IF NOT FOUND THEN
  39. RAISE EXCEPTION 'Cannot revoke permissions from a non-existant user.';
  40. END IF;
  41. stmt := 'REVOKE '|| quote_ident(in_role) ||' FROM '|| quote_ident(in_user);
  42. EXECUTE stmt;
  43. return 1;
  44. END;
  45. $$ language 'plpgsql';
  46. CREATE OR REPLACE FUNCTION admin_add_function_to_group(in_func TEXT, in_role TEXT) returns INT AS $$
  47. declare
  48. stmt TEXT;
  49. a_role name;
  50. a_user name;
  51. BEGIN
  52. -- Issue the grant
  53. select rolname into a_role from pg_roles where rolname = in_role;
  54. IF NOT FOUND THEN
  55. RAISE EXCEPTION 'Cannot grant permissions of a non-existant role.';
  56. END IF;
  57. select rolname into a_user from pg_roles where rolname = in_user;
  58. IF NOT FOUND THEN
  59. RAISE EXCEPTION 'Cannot grant permissions to a non-existant user.';
  60. END IF;
  61. stmt := 'GRANT EXECUTE ON FUNCTION '|| quote_ident(in_func) ||' to '|| quote_ident(in_role);
  62. EXECUTE stmt;
  63. return 1;
  64. END;
  65. $$ language 'plpgsql';
  66. CREATE OR REPLACE FUNCTION admin_remove_function_from_group(in_func TEXT, in_role TEXT) returns INT AS $$
  67. declare
  68. stmt TEXT;
  69. a_role name;
  70. a_user name;
  71. BEGIN
  72. -- Issue the grant
  73. select rolname into a_role from pg_roles where rolname = in_role;
  74. IF NOT FOUND THEN
  75. RAISE EXCEPTION 'Cannot revoke permissions of a non-existant role.';
  76. END IF;
  77. select rolname into a_user from pg_roles where rolname = in_user;
  78. IF NOT FOUND THEN
  79. RAISE EXCEPTION 'Cannot revoke permissions from a non-existant function.';
  80. END IF;
  81. stmt := 'REVOKE EXECUTE ON FUNCTION '|| quote_ident(in_func) ||' FROM '|| quote_ident(in_role);
  82. EXECUTE stmt;
  83. return 1;
  84. END;
  85. $$ language 'plpgsql';
  86. CREATE OR REPLACE FUNCTION admin_add_table_to_group(in_table TEXT, in_role TEXT, in_perm TEXT) returns INT AS $$
  87. declare
  88. stmt TEXT;
  89. a_role name;
  90. a_user name;
  91. BEGIN
  92. -- Issue the grant
  93. select rolname into a_role from pg_roles where rolname = in_role;
  94. IF NOT FOUND THEN
  95. RAISE EXCEPTION 'Cannot grant permissions of a non-existant role.';
  96. END IF;
  97. select table_name into a_table from information_schema.tables
  98. where table_schema NOT IN ('information_schema','pg_catalog','pg_toast')
  99. and table_type='BASE TABLE'
  100. and table_name = in_table;
  101. IF NOT FOUND THEN
  102. RAISE EXCEPTION 'Cannot grant permissions to a non-existant table.';
  103. END IF;
  104. if lower(in_perm) not in ('select','insert','update','delete') THEN
  105. raise exception 'Cannot add unknown permission';
  106. END IF;
  107. stmt := 'GRANT '|| quote_ident(in_perm) || 'ON TABLE '|| quote_ident(in_table) ||' to '|| quote_ident(in_role);
  108. EXECUTE stmt;
  109. return 1;
  110. END;
  111. $$ language 'plpgsql';
  112. CREATE OR REPLACE FUNCTION admin_remove_table_from_group(in_table TEXT, in_role TEXT) returns INT AS $$
  113. declare
  114. stmt TEXT;
  115. a_role name;
  116. a_table text;
  117. BEGIN
  118. -- Issue the grant
  119. select rolname into a_role from pg_roles where rolname = in_role;
  120. IF NOT FOUND THEN
  121. RAISE EXCEPTION 'Cannot revoke permissions of a non-existant role.';
  122. END IF;
  123. select table_name into a_table from information_schema.tables
  124. where table_schema NOT IN ('information_schema','pg_catalog','pg_toast')
  125. and table_type='BASE TABLE'
  126. and table_name = in_table;
  127. IF NOT FOUND THEN
  128. RAISE EXCEPTION 'Cannot revoke permissions from a non-existant table.';
  129. END IF;
  130. stmt := 'REVOKE '|| quote_literal(in_role) ||' FROM '|| quote_literal(in_user);
  131. EXECUTE stmt;
  132. return 1;
  133. END;
  134. $$ language 'plpgsql';
  135. create or replace function admin_get_user(in_user TEXT) returns setof users as $$
  136. DECLARE
  137. a_user users;
  138. BEGIN
  139. select * into a_user from users where username = in_user;
  140. IF NOT FOUND THEN
  141. RAISE EXCEPTION 'cannot find user %', in_user;
  142. END IF;
  143. return next a_user;
  144. return;
  145. END;
  146. $$ language plpgsql;
  147. create or replace function admin_get_roles_for_user(in_user TEXT) returns setof lsmb_roles as $$
  148. declare
  149. u_role lsmb_roles;
  150. a_user users;
  151. begin
  152. select * into a_user from admin_get_user(in_user);
  153. FOR u_role IN select * from lsmb_roles lr WHERE lr.user_id = a_user.id LOOP
  154. RETURN NEXT u_role;
  155. END LOOP;
  156. RETURN;
  157. end;
  158. $$ language 'plpgsql';
  159. CREATE OR REPLACE FUNCTION admin_save_user(
  160. in_id int,
  161. in_entity_id INT,
  162. in_username text,
  163. in_password TEXT
  164. ) returns int AS $$
  165. DECLARE
  166. a_user users;
  167. v_user_id int;
  168. p_id int;
  169. l_id int;
  170. stmt text;
  171. BEGIN
  172. select * into a_user from users lu where lu.id = in_id;
  173. IF NOT FOUND THEN
  174. -- Insert cycle
  175. --- The entity is expected to already BE created. See admin.pm.
  176. if admin_is_user(in_username) then
  177. -- uhm, this is bad.
  178. RAISE EXCEPTION 'Fatal exception: Username already exists in Postgres; not
  179. a valid lsmb user.';
  180. end if;
  181. -- create an actual user
  182. v_user_id := nextval('users_id_seq');
  183. insert into users (id, username, entity_id) VALUES (
  184. v_user_id,
  185. in_username,
  186. in_entity_id
  187. );
  188. insert into user_preference (id) values (v_user_id);
  189. -- Finally, issue the create user statement
  190. stmt := 'CREATE USER ' || quote_ident( in_username ) || ' WITH ENCRYPTED PASSWORD ' || quote_literal (in_password);
  191. execute stmt;
  192. return v_user_id ;
  193. ELSIF FOUND THEN
  194. -- update cycle
  195. stmt := ' alter user '|| quote_ident(in_username) || ' with encrypted password ' || quote_literal(in_password);
  196. execute stmt;
  197. return a_user.id;
  198. END IF;
  199. END;
  200. $$ language 'plpgsql';
  201. create view role_view as
  202. select * from pg_auth_members m join pg_authid a ON (m.roleid = a.oid);
  203. create or replace function admin_is_group(in_group_name text) returns bool as $$
  204. DECLARE
  205. existant_role role_view;
  206. stmt text;
  207. BEGIN
  208. select * into role_view from role_view where rolname = in_group_name;
  209. if not found then
  210. return 'f'::bool;
  211. else
  212. return 't'::bool;
  213. end if;
  214. END;
  215. $$ language 'plpgsql';
  216. CREATE OR REPLACE FUNCTION admin_create_group(in_group_name TEXT, in_dbname TEXT) RETURNS int as $$
  217. DECLARE
  218. stmt text;
  219. BEGIN
  220. stmt := 'create role '|| quote_ident(quote_ident(in_dbname) || '_lsmb_' || quote_ident(in_group_name) );
  221. execute stmt;
  222. return 1;
  223. END;
  224. $$ language 'plpgsql';
  225. CREATE OR REPLACE FUNCTION admin_delete_user(in_username TEXT) returns INT as $$
  226. DECLARE
  227. stmt text;
  228. a_user users;
  229. BEGIN
  230. select * into a_user from users where username = in_username;
  231. IF NOT FOUND THEN
  232. raise exception 'User not found.';
  233. ELSIF FOUND THEN
  234. stmt := ' drop user ' || quote_ident(a_user.username);
  235. execute stmt;
  236. -- also gets user_connection
  237. delete from users where id = a_user.id;
  238. delete from entity where id = a_user.entity_id;
  239. END IF;
  240. END;
  241. $$ language 'plpgsql';
  242. comment on function admin_delete_user(text) is $$
  243. Drops the provided user, as well as deletes the entity and user configuration data.
  244. $$;
  245. CREATE OR REPLACE FUNCTION admin_delete_group (in_dbname TEXT, in_group_name TEXT) returns bool as $$
  246. DECLARE
  247. stmt text;
  248. a_role role_view;
  249. BEGIN
  250. select * into a_role from role_view where rolname = in_group_name;
  251. if not found then
  252. return 'f'::bool;
  253. else
  254. stmt := 'drop role ' || quote_ident(in_dbname || '_lsmb_' || in_group_name);
  255. execute stmt;
  256. return 't'::bool;
  257. end if;
  258. END;
  259. $$ language 'plpgsql';
  260. comment on function admin_delete_group(text,text) IS $$
  261. Deletes the input group from the database. Not designed to be used to
  262. remove a login-capable user.
  263. $$;
  264. CREATE OR REPLACE FUNCTION admin_list_roles(in_username text)
  265. RETURNS SETOF text AS
  266. $$
  267. DECLARE out_rolename RECORD;
  268. BEGIN
  269. FOR out_rolename IN
  270. SELECT rolname FROM pg_authid
  271. WHERE oid IN (SELECT id FROM connectby(
  272. '(SELECT m.member, m.roleid, r.oid FROM pg_authid r
  273. LEFT JOIN pg_auth_members m ON (r.oid = m.roleid)) a',
  274. 'oid', 'member', 'oid', '320461', '0', ','
  275. ) c(id integer, parent integer, "level" integer,
  276. path text, list_order integer)
  277. )
  278. LOOP
  279. RETURN NEXT out_rolename.rolname;
  280. END LOOP;
  281. END;
  282. $$ LANGUAGE PLPGSQL;
  283. -- TODO: Add admin user
  284. --CREATE OR REPLACE FUNCTION admin_audit_log () returns int as $$
  285. --$$ language plpgsql;
  286. create or replace function admin_is_user (in_user text) returns bool as $$
  287. DECLARE
  288. pg_user pg_roles;
  289. BEGIN
  290. select * into pg_user from pg_roles where rolname = in_user;
  291. IF NOT FOUND THEN
  292. return 'f'::bool;
  293. END IF;
  294. return 't'::bool;
  295. END;
  296. $$ language plpgsql;
  297. create or replace function admin_is_user (in_user text) returns bool as $$
  298. BEGIN
  299. return 'f'::bool;
  300. END;
  301. $$ language plpgsql;
  302. create or replace view user_listable as
  303. select
  304. u.id,
  305. u.username,
  306. e.created
  307. from entity e
  308. join users u on u.entity_id = e.id;
  309. create or replace function user_get_all_users () returns setof user_listable as $$
  310. select * from user_listable;
  311. $$ language sql;
  312. commit;