Skip to content
Snippets Groups Projects
Commit bffa0521 authored by User expired's avatar User expired
Browse files

Merge branch 'production_uibk' into 'uibk'

changes to postgres_db_structure_functions.sql

See merge request !29
parents f57bdbd9 d8419253
No related branches found
No related tags found
1 merge request!3160210 ip4
......@@ -3,6 +3,13 @@
ALTER TABLE tce_user_groups ADD COLUMN external_id varchar(255);
-- modifying the schema to assign a study key to user in group
ALTER TABLE tce_usrgroups ADD COLUMN usrgrp_studykey character varying(255);
ALTER TABLE tce_tests_users ADD COLUMN testuser_studykey character varying(255);
-- functions for tcexam esb integration
-- assign_tcexam_user_to_group
......@@ -12,22 +19,26 @@ CREATE OR REPLACE FUNCTION assign_tcexam_user_to_group(xmlbody text, pgroupid ch
$BODY$
DECLARE
login character varying;
externalid character varying;
userid bigint;
groupid bigint;
uservo xml;
externalid character varying;
userid bigint;
groupid bigint;
studykey character varying;
uservo xml;
BEGIN
uservo = xmlbody::xml;
BEGIN
uservo = xmlbody::xml;
externalid = CONCAT (pgroupid,':',pappointmentid);
SELECT (xpath('/userVO/login/text()', uservo))[1] into login;
SELECT user_id INTO userid FROM tce_users WHERE user_name = login;
SELECT group_id INTO groupid FROM tce_user_groups WHERE external_id = externalid ;
SELECT (xpath('/userVO/appointmentStudyKey/text()', uservo))[1] into studykey;
INSERT INTO tce_usrgroups (usrgrp_user_id, usrgrp_group_id) VALUES (userid, groupid);
SELECT user_id INTO userid FROM tce_users WHERE user_name = login;
SELECT group_id INTO groupid FROM tce_user_groups WHERE external_id = externalid;
IF NOT EXISTS(SELECT usrgrp_user_id FROM tce_usrgroups WHERE usrgrp_group_id = groupid AND usrgrp_user_id = userid)
THEN INSERT INTO tce_usrgroups (usrgrp_user_id, usrgrp_group_id, usrgrp_studykey) VALUES (userid, groupid, studykey);
ELSE UPDATE tce_usrgroups SET usrgrp_studykey = studykey WHERE usrgrp_group_id = groupid and usrgrp_user_id = userid;
END IF;
END;
$BODY$
......@@ -38,25 +49,6 @@ $BODY$
ALTER FUNCTION assign_tcexam_user_to_group(text, character varying, character varying)
OWNER TO tcexam;
-- delete_tcexam_user
CREATE OR REPLACE FUNCTION delete_tcexam_user(login character varying)
RETURNS void AS
$BODY$
BEGIN
-- delete only if no tests for this user available
IF (SELECT COUNT(*) FROM (SELECT user_id, user_name FROM tce_users u INNER JOIN tce_tests t ON (t.test_user_id = u.user_id) where u.user_name = login) AS numberofusers) = 0 THEN
DELETE FROM tce_users WHERE user_name = login;
END IF;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
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)
OWNER TO tcexam;
-- get_tcexam_group
......@@ -64,7 +56,6 @@ CREATE OR REPLACE FUNCTION get_tcexam_group(externalid character varying)
RETURNS text AS
$BODY$
DECLARE
xoutput text;
......@@ -106,7 +97,6 @@ ALTER FUNCTION get_tcexam_group(character varying)
-- get_tcexam_group_appointment_users
CREATE OR REPLACE FUNCTION get_tcexam_group_appointment_users(pgroupid character varying, pappointmentid character varying)
RETURNS text AS
$BODY$
......@@ -125,7 +115,7 @@ SELECT XMLSERIALIZE ( CONTENT
XMLFOREST(u.user_firstname),
XMLFOREST(u.user_lastname),
XMLFOREST(u.user_level)
))) as text )
INTO xoutput
FROM tce_user_groups g
......@@ -200,7 +190,6 @@ SELECT XMLSERIALIZE ( CONTENT
XMLFOREST(u.user_lastname),
XMLFOREST(u.user_regnumber),
XMLFOREST(u.user_level)
))) as text )
INTO xoutput
FROM tce_users u
......@@ -214,8 +203,7 @@ $function$
-- insert_tcexam_group
CREATE OR REPLACE FUNCTION insert_tcexam_group(xmlbody text, pgroupid character varying, pappointmentid character varying, pgroupname character varying)
CREATE OR REPLACE FUNCTION insert_tcexam_group(pgroupid character varying, pappointmentid character varying, pgroupname character varying)
RETURNS void AS
$BODY$
DECLARE
......@@ -225,16 +213,12 @@ DECLARE
BEGIN
groupvo = xmlbody::xml;
externalid = CONCAT (pgroupid,':',pappointmentid);
IF NOT EXISTS(SELECT group_id FROM tce_user_groups WHERE external_id = externalid)
THEN
INSERT INTO tce_user_groups (group_name, external_id) VALUES (pgroupname,externalid);
END IF;
END;
$BODY$
......@@ -274,6 +258,7 @@ AS $function$
THEN
INSERT INTO tce_users (user_name, user_email, user_firstname, user_lastname, user_regnumber, user_level, user_regdate, user_password, user_ip)
VALUES (login,email,firstname,lastname, matrikelnr, 1, now(), 'no£password', '127.0.0.1');
INSERT INTO tce_usrgroups (usrgrp_user_id,usrgrp_group_id) VALUES ((SELECT user_id FROM tce_users WHERE user_name = login),1);
END IF;
END;
......@@ -312,6 +297,24 @@ ALTER FUNCTION remove_tcexam_user_from_group(text, character varying, character
OWNER TO tcexam;
-- Function: set_tcexam_user_level(character varying, integer)
CREATE OR REPLACE FUNCTION set_tcexam_user_level(login character varying, ulevel integer)
RETURNS void AS
$BODY$
BEGIN
UPDATE tce_users SET user_level = ulevel WHERE user_name = login;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
SECURITY DEFINER
-- Set a secure search_path: trusted schema(s), then 'pg_temp'.
SET search_path = tcexam, pg_temp;
ALTER FUNCTION set_tcexam_user_level(character varying, integer)
OWNER TO tcexam;
-- update_tcexam_group
......@@ -320,7 +323,7 @@ CREATE OR REPLACE FUNCTION update_tcexam_group(pgroupid character varying, pappo
$BODY$
DECLARE
theKey character varying;
BEGIN
theKey = pgroupid || ':' || pappointmentid;
......@@ -355,7 +358,7 @@ AS $function$
userstatus character varying;
userlevel integer;
uservo xml;
BEGIN
uservo = xmlbody::xml;
......@@ -390,7 +393,6 @@ ALTER FUNCTION update_tcexam_user(text)
OWNER TO tcexam;
-- create esb user
-- CREATE USER esb WITH PASSWORD '....';
......@@ -401,7 +403,6 @@ ALTER FUNCTION update_tcexam_user(text)
-- # 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 delete_tcexam_user(login character varying) TO esb;
GRANT EXECUTE ON FUNCTION get_tcexam_group(externalid character varying) TO esb;
GRANT EXECUTE ON FUNCTION get_tcexam_group_appointment_users(pgroupid character varying, pappointmentid character varying) TO esb;
GRANT EXECUTE ON FUNCTION get_tcexam_group_users(group_id character varying) TO esb;
......@@ -409,5 +410,6 @@ GRANT EXECUTE ON FUNCTION get_tcexam_user(userid character varying) 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 insert_tcexam_user(xmlbody text) 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 set_tcexam_user_level(character varying, 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;
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