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