Commit c3a19945 authored by Daniel Haag's avatar Daniel Haag
Browse files

postgres functions for esb integration updated

parent 0a1e7b79
-- modifying the schema to allow an external_id
ALTER TABLE tce_user_groups ADD COLUMN external_id varchar(255);
-- functions for tcexam esb integration -- functions for tcexam esb integration
-- assign_tcexam_user_to_group -- assign_tcexam_user_to_group
...@@ -28,9 +32,11 @@ $BODY$ ...@@ -28,9 +32,11 @@ $BODY$
END; END;
$BODY$ $BODY$
LANGUAGE plpgsql VOLATILE LANGUAGE plpgsql VOLATILE
COST 100; SECURITY DEFINER
-- Set a secure search_path: trusted schema(s), then 'pg_temp'.
SET search_path = tcexam, pg_temp;
ALTER FUNCTION assign_tcexam_user_to_group(text, character varying, character varying) ALTER FUNCTION assign_tcexam_user_to_group(text, character varying, character varying)
OWNER TO postgres; OWNER TO tcexam;
-- delete_tcexam_user -- delete_tcexam_user
...@@ -46,9 +52,11 @@ $BODY$ ...@@ -46,9 +52,11 @@ $BODY$
END; END;
$BODY$ $BODY$
LANGUAGE plpgsql VOLATILE LANGUAGE plpgsql VOLATILE
COST 1; SECURITY DEFINER
-- Set a secure search_path: trusted schema(s), then 'pg_temp'.
SET search_path = tcexam, pg_temp;
ALTER FUNCTION delete_tcexam_user(character varying) ALTER FUNCTION delete_tcexam_user(character varying)
OWNER TO postgres; OWNER TO tcexam;
-- get_tcexam_group -- get_tcexam_group
...@@ -89,9 +97,11 @@ SELECT XMLSERIALIZE ( CONTENT ...@@ -89,9 +97,11 @@ SELECT XMLSERIALIZE ( CONTENT
END; END;
$BODY$ $BODY$
LANGUAGE plpgsql VOLATILE LANGUAGE plpgsql VOLATILE
COST 1; SECURITY DEFINER
-- Set a secure search_path: trusted schema(s), then 'pg_temp'.
SET search_path = tcexam, pg_temp;
ALTER FUNCTION get_tcexam_group(character varying) ALTER FUNCTION get_tcexam_group(character varying)
OWNER TO postgres; OWNER TO tcexam;
-- get_tcexam_group_appointment_users -- get_tcexam_group_appointment_users
...@@ -109,25 +119,29 @@ SELECT XMLSERIALIZE ( CONTENT ...@@ -109,25 +119,29 @@ SELECT XMLSERIALIZE ( CONTENT
XMLELEMENT(name "userVOes", XMLELEMENT(name "userVOes",
xmlagg( xmlagg(
XMLELEMENT(name "userVO", XMLELEMENT(name "userVO",
XMLFOREST(user_id), XMLFOREST(u.user_id),
XMLFOREST(user_name as login), XMLFOREST(u.user_name as login),
XMLFOREST(user_email), XMLFOREST(u.user_email),
XMLFOREST(user_firstname), XMLFOREST(u.user_firstname),
XMLFOREST(user_lastname), XMLFOREST(u.user_lastname),
XMLFOREST(user_level) XMLFOREST(u.user_level)
))) as text ) ))) as text )
INTO xoutput INTO xoutput
FROM users_and_groups u FROM tce_user_groups g
WHERE u.external_id = concat(pgroupid,':',pappointmentid) LEFT JOIN tce_usrgroups ug ON g.group_id = ug.usrgrp_group_id
LEFT JOIN tce_users u ON u.user_id = ug.usrgrp_user_id
WHERE g.external_id = concat(pgroupid,':',pappointmentid)
; ;
RETURN xoutput; RETURN xoutput;
END; END;
$BODY$ $BODY$
LANGUAGE plpgsql VOLATILE LANGUAGE plpgsql VOLATILE
COST 1; SECURITY DEFINER
-- Set a secure search_path: trusted schema(s), then 'pg_temp'.
SET search_path = tcexam, pg_temp;
ALTER FUNCTION get_tcexam_group_appointment_users(character varying, character varying) ALTER FUNCTION get_tcexam_group_appointment_users(character varying, character varying)
OWNER TO postgres; OWNER TO tcexam;
-- get_tcexam_group_users -- get_tcexam_group_users
...@@ -140,24 +154,29 @@ SELECT XMLSERIALIZE ( CONTENT ...@@ -140,24 +154,29 @@ SELECT XMLSERIALIZE ( CONTENT
XMLELEMENT(name "userVOes", XMLELEMENT(name "userVOes",
xmlagg( xmlagg(
XMLELEMENT(name "userVO", XMLELEMENT(name "userVO",
XMLFOREST(user_id), XMLFOREST(u.user_id),
XMLFOREST(user_name as login), XMLFOREST(u.user_name as login),
XMLFOREST(user_email), XMLFOREST(u.user_email),
XMLFOREST(user_firstname), XMLFOREST(u.user_firstname),
XMLFOREST(user_lastname), XMLFOREST(u.user_lastname),
XMLFOREST(user_level) XMLFOREST(u.user_level)
)
))) as text ) )
FROM (SELECT * FROM ( ) as text )
SELECT * FROM tce_user_groups g
LEFT JOIN tce_usrgroups ug ON g.group_id = ug.usrgrp_group_id) ug FROM tce_user_groups g
LEFT JOIN tce_users u ON u.user_id = ug.usrgrp_user_id) u LEFT JOIN tce_usrgroups ug ON g.group_id = ug.usrgrp_group_id
WHERE u.external_id LIKE concat($1,':%') LEFT JOIN tce_users u ON u.user_id = ug.usrgrp_user_id
; WHERE g.external_id LIKE concat($1,':%');
$BODY$ $BODY$
LANGUAGE sql VOLATILE LANGUAGE sql VOLATILE
COST 1; SECURITY DEFINER
-- Set a secure search_path: trusted schema(s), then 'pg_temp'.
SET search_path = tcexam, pg_temp;
ALTER FUNCTION get_tcexam_group_users(character varying)
OWNER TO tcexam;
...@@ -188,9 +207,11 @@ BEGIN ...@@ -188,9 +207,11 @@ BEGIN
END; END;
$BODY$ $BODY$
LANGUAGE plpgsql VOLATILE LANGUAGE plpgsql VOLATILE
COST 1; SECURITY DEFINER
-- Set a secure search_path: trusted schema(s), then 'pg_temp'.
SET search_path = tcexam, pg_temp;
ALTER FUNCTION insert_tcexam_group(text, character varying, character varying, character varying) ALTER FUNCTION insert_tcexam_group(text, character varying, character varying, character varying)
OWNER TO postgres; OWNER TO tcexam;
-- insert_tcexam_user -- insert_tcexam_user
...@@ -223,9 +244,11 @@ $BODY$ ...@@ -223,9 +244,11 @@ $BODY$
END; END;
$BODY$ $BODY$
LANGUAGE plpgsql VOLATILE LANGUAGE plpgsql VOLATILE
COST 100; SECURITY DEFINER
-- Set a secure search_path: trusted schema(s), then 'pg_temp'.
SET search_path = tcexam, pg_temp;
ALTER FUNCTION insert_tcexam_user(text, character varying, character varying) ALTER FUNCTION insert_tcexam_user(text, character varying, character varying)
OWNER TO postgres; OWNER TO tcexam;
-- remove_tcexam_user_from_group -- remove_tcexam_user_from_group
...@@ -251,9 +274,11 @@ $BODY$ ...@@ -251,9 +274,11 @@ $BODY$
END; END;
$BODY$ $BODY$
LANGUAGE plpgsql VOLATILE LANGUAGE plpgsql VOLATILE
COST 1; SECURITY DEFINER
-- Set a secure search_path: trusted schema(s), then 'pg_temp'.
SET search_path = tcexam, pg_temp;
ALTER FUNCTION remove_tcexam_user_from_group(text, character varying, character varying) ALTER FUNCTION remove_tcexam_user_from_group(text, character varying, character varying)
OWNER TO postgres; OWNER TO tcexam;
-- update_tcexam_group -- update_tcexam_group
...@@ -275,9 +300,11 @@ BEGIN ...@@ -275,9 +300,11 @@ BEGIN
END; END;
$BODY$ $BODY$
LANGUAGE plpgsql VOLATILE LANGUAGE plpgsql VOLATILE
COST 1; SECURITY DEFINER
-- Set a secure search_path: trusted schema(s), then 'pg_temp'.
SET search_path = tcexam, pg_temp;
ALTER FUNCTION update_tcexam_group(character varying, character varying, character varying) ALTER FUNCTION update_tcexam_group(character varying, character varying, character varying)
OWNER TO postgres; OWNER TO tcexam;
-- update_tcexam_user -- update_tcexam_user
...@@ -315,9 +342,11 @@ $BODY$ ...@@ -315,9 +342,11 @@ $BODY$
END; END;
$BODY$ $BODY$
LANGUAGE plpgsql VOLATILE LANGUAGE plpgsql VOLATILE
COST 1; SECURITY DEFINER
-- Set a secure search_path: trusted schema(s), then 'pg_temp'.
SET search_path = tcexam, pg_temp;
ALTER FUNCTION update_tcexam_user(text, character varying, character varying) ALTER FUNCTION update_tcexam_user(text, character varying, character varying)
OWNER TO postgres; OWNER TO tcexam;
-- create esb user -- create esb user
...@@ -325,14 +354,17 @@ ALTER FUNCTION update_tcexam_user(text, character varying, character varying) ...@@ -325,14 +354,17 @@ ALTER FUNCTION update_tcexam_user(text, character varying, character varying)
-- CREATE USER esb WITH PASSWORD '....'; -- CREATE USER esb WITH PASSWORD '....';
-- grant execute right on the functions -- grant execute right on the functions
--
GRANT EXECUTE ON FUNCTION assign_tcexam_user_to_group TO esb; -- # Generated with:
GRANT EXECUTE ON FUNCTION delete_tcexam_user TO esb; -- # grep 'CREATE OR REPLACE FUNCTION' postgres_db_structure_functions.sql | sed 's/CREATE OR REPLACE FUNCTION //' | while read f; do echo "GRANT EXECUTE ON FUNCTION $f TO esb;"; done
GRANT EXECUTE ON FUNCTION get_tcexam_group TO esb;
GRANT EXECUTE ON FUNCTION get_tcexam_group_appointment_users TO esb; GRANT EXECUTE ON FUNCTION assign_tcexam_user_to_group(xmlbody text, pgroupid character varying, pappointmentid character varying) TO esb;
GRANT EXECUTE ON FUNCTION get_tcexam_group_users TO esb; GRANT EXECUTE ON FUNCTION delete_tcexam_user(login character varying) TO esb;
GRANT EXECUTE ON FUNCTION insert_tcexam_group TO esb; GRANT EXECUTE ON FUNCTION get_tcexam_group(externalid character varying) TO esb;
GRANT EXECUTE ON FUNCTION insert_tcexam_user TO esb; GRANT EXECUTE ON FUNCTION get_tcexam_group_appointment_users(pgroupid character varying, pappointmentid character varying) TO esb;
GRANT EXECUTE ON FUNCTION remove_tcexam_user_from_group TO esb; GRANT EXECUTE ON FUNCTION get_tcexam_group_users(group_id character varying) TO esb;
GRANT EXECUTE ON FUNCTION update_tcexam_group TO esb; GRANT EXECUTE ON FUNCTION insert_tcexam_group(xmlbody text, pgroupid character varying, pappointmentid character varying, pgroupname character varying) TO esb;
GRANT EXECUTE ON FUNCTION update_tcexam_user TO esb; GRANT EXECUTE ON FUNCTION insert_tcexam_user(xmlbody text, pgroupid character varying, pappointmentid character varying) TO esb;
GRANT EXECUTE ON FUNCTION remove_tcexam_user_from_group(xmlbody text, pgroupid character varying, pappointmentid character varying) TO esb;
GRANT EXECUTE ON FUNCTION update_tcexam_group(pgroupid character varying, pappointmentid character varying, pgroupname character varying) TO esb;
GRANT EXECUTE ON FUNCTION update_tcexam_user(xmlbody text, pgroupid character varying, pappointmentid character varying) TO esb;
Markdown is supported
0% or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment