Skip to content
Snippets Groups Projects
Commit 80467143 authored by Ewald Strohmar-Mauler's avatar Ewald Strohmar-Mauler
Browse files

new postgresql functions for esb reminder emails

parent b7260082
No related branches found
No related tags found
3 merge requests!8160524,!6160524,!5160512
......@@ -9,6 +9,17 @@ ALTER TABLE tce_usrgroups ADD COLUMN usrgrp_studykey character varying(255);
ALTER TABLE tce_tests_users ADD COLUMN testuser_studykey character varying(255);
-- modifying to log sent reminder emails
ALTER TABLE tce_user_groups ADD email1_sent character varying(255);
ALTER TABLE tce_user_groups ADD email2_sent character varying(255);
ALTER TABLE tce_user_groups ADD email3_sent character varying(255);
ALTER TABLE tce_user_groups ADD disabled character varying(255);
-- restraint dropped because a user locked in VIS can be registered again in TCExam later, but of course keeps his matrikelnr.
ALTER TABLE tce_users DROP CONSTRAINT ak_user_regnumber;
-- functions for tcexam esb integration
......@@ -170,6 +181,9 @@ ALTER FUNCTION get_tcexam_group_users(character varying)
-- get tcexam_user
CREATE OR REPLACE FUNCTION get_tcexam_user(userid character varying)
RETURNS text
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path TO tcexam, pg_temp
AS $function$
DECLARE
......@@ -195,11 +209,7 @@ WHERE u.user_name = userid
RETURN xoutput;
END;
$function$
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path TO tcexam, pg_temp;
ALTER FUNCTION get_tcexam_user(character varying)
OWNER TO tcexam;
-- insert_tcexam_group
......@@ -227,7 +237,7 @@ $BODY$
SECURITY DEFINER
-- Set a secure search_path: trusted schema(s), then 'pg_temp'.
SET search_path = tcexam, pg_temp;
ALTER FUNCTION insert_tcexam_group(character varying, character varying, character varying)
ALTER FUNCTION insert_tcexam_group(text, character varying, character varying, character varying)
OWNER TO tcexam;
......@@ -235,6 +245,9 @@ ALTER FUNCTION insert_tcexam_group(character varying, character varying, charact
CREATE OR REPLACE FUNCTION insert_tcexam_user(xmlbody text)
RETURNS void
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path TO tcexam, pg_temp
AS $function$
DECLARE
login character varying;
......@@ -261,9 +274,7 @@ AS $function$
END;
$function$
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path TO tcexam, pg_temp;
ALTER FUNCTION insert_tcexam_user(text)
OWNER TO tcexam;
......@@ -345,6 +356,9 @@ ALTER FUNCTION update_tcexam_group(character varying, character varying, charact
CREATE OR REPLACE FUNCTION update_tcexam_user(xmlbody text)
RETURNS void
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path TO tcexam, pg_temp
AS $function$
DECLARE
login character varying;
......@@ -385,12 +399,155 @@ AS $function$
END;
$function$
LANGUAGE plpgsql
SECURITY DEFINER
SET search_path TO tcexam, pg_temp;
ALTER FUNCTION update_tcexam_user(text)
OWNER TO tcexam;
-- Function: get_tcexam_recent_tests(character varying)
-- DROP FUNCTION get_tcexam_recent_tests(character varying);
CREATE OR REPLACE FUNCTION get_tcexam_recent_tests(externalid character varying)
RETURNS text AS
$BODY$
DECLARE
xoutput text;
BEGIN
SELECT XMLSERIALIZE ( CONTENT
XMLELEMENT(name "recentTests",
xmlagg(
XMLELEMENT(name "test",
XMLFOREST(
t.test_id as "testId",
t.test_name as "testName",
u.group_id as "groupId"
)
)
)
)
as text )
INTO xoutput
FROM tce_user_groups u, tce_testgroups tg, tce_tests t
WHERE u.group_id = tg.tstgrp_group_id
AND u.external_id LIKE concat(externalid,':%') AND u.external_id != concat(externalid,':owner') AND u.email2_sent IS NULL
AND t.test_id = tg.tstgrp_test_id AND t.test_end_time BETWEEN current_date - 8 AND current_date - 1;
RETURN xoutput;
END;
$BODY$
LANGUAGE plpgsql VOLATILE SECURITY DEFINER;
ALTER FUNCTION get_tcexam_recent_tests(character varying) SET search_path=tcexam, pg_temp;
ALTER FUNCTION get_tcexam_recent_tests(character varying) OWNER TO tcexam;
GRANT EXECUTE ON FUNCTION get_tcexam_recent_tests(character varying) TO public;
GRANT EXECUTE ON FUNCTION get_tcexam_recent_tests(character varying) TO tcexam;
GRANT EXECUTE ON FUNCTION get_tcexam_recent_tests(character varying) TO esb;
-- Function: set_tcexam_email_sent(character varying, integer)
-- DROP FUNCTION set_tcexam_email_sent(character varying, integer);
CREATE OR REPLACE FUNCTION set_tcexam_email_sent(groupid character varying, emailnumber integer)
RETURNS text AS
$BODY$
DECLARE found text;
BEGIN
EXECUTE 'SELECT email' || emailnumber || '_sent FROM tce_user_groups WHERE group_id =' || groupid ||';' INTO found;
IF found > '' THEN
RETURN '<result>existing</result>';
ELSE
EXECUTE 'UPDATE tce_user_groups SET email' || emailnumber || '_sent = current_date WHERE group_id = ' || groupid || ';';
RETURN '<result>new</result>';
END IF;
END;
$BODY$
LANGUAGE plpgsql VOLATILE SECURITY DEFINER;
ALTER FUNCTION set_tcexam_email_sent(character varying, integer) SET search_path=tcexam, pg_temp;
ALTER FUNCTION set_tcexam_email_sent(character varying, integer) OWNER TO tcexam;
GRANT EXECUTE ON FUNCTION set_tcexam_email_sent(character varying, integer) TO public;
GRANT EXECUTE ON FUNCTION set_tcexam_email_sent(character varying, integer) TO tcexam;
GRANT EXECUTE ON FUNCTION set_tcexam_email_sent(character varying, integer) TO esb;
-- Function: count_tcexam_users_by_exam(character varying, character varying)
-- DROP FUNCTION count_tcexam_users_by_exam(character varying, character varying);
CREATE OR REPLACE FUNCTION count_tcexam_users_by_exam(external_group_id character varying, external_appointment_id character varying)
RETURNS text AS
$BODY$
DECLARE
xoutput text;
BEGIN
SELECT XMLSERIALIZE ( CONTENT
XMLELEMENT(name "Appointments",
xmlagg(
XMLELEMENT(name "Appointment",
XMLFOREST(
u.external_id as "GroupId",
u.lv as "LV",
u.testdate as "TestDate",
u.usercount as "UserCount"
)
)
))
as text )
INTO xoutput
FROM
(SELECT foo.external_id, split_part(foo.group_name,' Gruppe 0 - Prüfungstermin: ',1) as lv, split_part(foo.group_name,' Gruppe 0 - Prüfungstermin: ',2) as testdate, count(usrgrp_user_id) as UserCount FROM (
SELECT * FROM tce_usrgroups g
LEFT JOIN tce_user_groups ug ON ug.group_id = g.usrgrp_group_id
WHERE ug.external_id LIKE CONCAT($1,':',$2) AND ug.external_id NOT LIKE ('%owner%')
)
AS foo
GROUP BY foo.external_id, foo.group_name
ORDER BY foo.external_id) as u
;
RETURN xoutput;
END;
$BODY$
LANGUAGE plpgsql VOLATILE;
ALTER FUNCTION count_tcexam_users_by_exam(character varying, character varying) SET search_path=tcexam, pg_temp;
ALTER FUNCTION count_tcexam_users_by_exam(character varying, character varying) OWNER TO tcexam;
GRANT EXECUTE ON FUNCTION count_tcexam_users_by_exam(character varying, character varying) TO public;
GRANT EXECUTE ON FUNCTION count_tcexam_users_by_exam(character varying, character varying) TO tcexam;
GRANT EXECUTE ON FUNCTION count_tcexam_users_by_exam(character varying, character varying) TO esb;
-- Function: get_tcexam_groupid(character varying, character varying)
-- DROP FUNCTION get_tcexam_groupid(character varying, character varying);
CREATE OR REPLACE FUNCTION get_tcexam_groupid(pgroupid character varying, pappointmentid character varying)
RETURNS text AS
$BODY$
DECLARE
groupid text;
BEGIN
SELECT XMLSERIALIZE ( CONTENT
XMLFOREST(
group_id as "groupId")
as text )
INTO groupid
FROM tce_user_groups WHERE external_id = CONCAT(pgroupid,':',pappointmentid) ;
RETURN groupid;
END;
$BODY$
LANGUAGE plpgsql VOLATILE SECURITY DEFINER;
ALTER FUNCTION get_tcexam_groupid(character varying, character varying) SET search_path=tcexam, pg_temp;
ALTER FUNCTION get_tcexam_groupid(character varying, character varying) OWNER TO tcexam;
GRANT EXECUTE ON FUNCTION get_tcexam_groupid(character varying, character varying) TO public;
GRANT EXECUTE ON FUNCTION get_tcexam_groupid(character varying, character varying) TO tcexam;
GRANT EXECUTE ON FUNCTION get_tcexam_groupid(character varying, character varying) TO esb;
-- create esb user
......@@ -399,7 +556,7 @@ ALTER FUNCTION update_tcexam_user(text)
-- grant execute right on the functions
--
-- # Generated with:
-- # 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
-- # 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 assign_tcexam_user_to_group(xmlbody text, pgroupid character varying, pappointmentid character varying) TO esb;
GRANT EXECUTE ON FUNCTION get_tcexam_group(externalid character varying) TO esb;
......@@ -412,3 +569,13 @@ GRANT EXECUTE ON FUNCTION remove_tcexam_user_from_group(xmlbody text, pgroupid c
GRANT EXECUTE ON FUNCTION set_tcexam_user_level(login character varying, ulevel integer) 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) TO esb;
GRANT EXECUTE ON FUNCTION get_tcexam_recent_tests(externalid character varying) TO esb;
GRANT EXECUTE ON FUNCTION set_tcexam_email_sent(groupid character varying, emailnumber integer) TO esb;
GRANT EXECUTE ON FUNCTION count_tcexam_users_by_exam(external_group_id character varying, external_appointment_id character varying) TO esb;
GRANT EXECUTE ON FUNCTION get_tcexam_groupid(pgroupid character varying, pappointmentid character varying) TO esb;
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment