Commit 96b6f4e5 authored by User expired's avatar User expired
Browse files

postgresql functions for ESB integration

parent 14f648b9
-- functions for tcexam integration
-- assign_tcexam_user_to_group
CREATE OR REPLACE FUNCTION assign_tcexam_user_to_group(xmlbody text, pgroupid character varying, pappointmentid character varying)
RETURNS void AS
$BODY$
DECLARE
login character varying;
externalid character varying;
userid bigint;
groupid bigint;
uservo 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 ;
INSERT INTO tce_usrgroups (usrgrp_user_id, usrgrp_group_id) VALUES (userid, groupid);
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
ALTER FUNCTION assign_tcexam_user_to_group(text, character varying, character varying)
OWNER TO postgres;
-- 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
COST 1;
ALTER FUNCTION delete_tcexam_user(character varying)
OWNER TO postgres;
-- get_tcexam_group
CREATE OR REPLACE FUNCTION get_tcexam_group(externalid character varying)
RETURNS text AS
$BODY$
DECLARE
xoutput text;
BEGIN
IF NOT EXISTS(SELECT group_name from tce_user_groups where external_id like concat(externalid,':%'))
THEN
RETURN '<appointments><appointment><appointmentId>' || '' || '</appointmentId></appointment></appointments>';
END IF;
SELECT XMLSERIALIZE ( CONTENT
XMLELEMENT(name "appointments",
xmlagg(
XMLELEMENT(name "appointment",
XMLFOREST(
split_part(u.external_id,':',2) as "appointmentId",
u.group_id as "tcexamGroupKey",
u.group_name as "tcexamGroupName"
)
)
)
)
as text )
INTO xoutput
FROM tce_user_groups u
WHERE u.external_id LIKE concat(externalid,':%')
;
RETURN xoutput;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 1;
ALTER FUNCTION get_tcexam_group(character varying)
OWNER TO postgres;
-- get_tcexam_group_appointment_users
CREATE OR REPLACE FUNCTION get_tcexam_group_appointment_users(pgroupid character varying, pappointmentid character varying)
RETURNS text AS
$BODY$
DECLARE
xoutput text;
BEGIN
SELECT XMLSERIALIZE ( CONTENT
XMLELEMENT(name "userVOes",
xmlagg(
XMLELEMENT(name "userVO",
XMLFOREST(user_id),
XMLFOREST(user_name as login),
XMLFOREST(user_email),
XMLFOREST(user_firstname),
XMLFOREST(user_lastname),
XMLFOREST(user_level)
))) as text )
INTO xoutput
FROM users_and_groups u
WHERE u.external_id = concat(pgroupid,':',pappointmentid)
;
RETURN xoutput;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 1;
ALTER FUNCTION get_tcexam_group_appointment_users(character varying, character varying)
OWNER TO postgres;
-- get_tcexam_group_users
CREATE OR REPLACE FUNCTION get_tcexam_group_users(group_id character varying)
RETURNS text AS
$BODY$
SELECT XMLSERIALIZE ( CONTENT
XMLELEMENT(name "userVOes",
xmlagg(
XMLELEMENT(name "userVO",
XMLFOREST(user_id),
XMLFOREST(user_name as login),
XMLFOREST(user_email),
XMLFOREST(user_firstname),
XMLFOREST(user_lastname),
XMLFOREST(user_level)
))) as text )
FROM users_and_groups u
WHERE u.external_id LIKE concat($1,':%')
;
$BODY$
LANGUAGE sql VOLATILE
COST 1;
ALTER FUNCTION get_tcexam_group_users(character varying)
OWNER TO postgres;
-- insert_tcexam_group
CREATE OR REPLACE FUNCTION insert_tcexam_group(xmlbody text, pgroupid character varying, pappointmentid character varying, pgroupname character varying)
RETURNS void AS
$BODY$
DECLARE
externalid character varying;
appointmentid character varying;
groupvo xml;
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$
LANGUAGE plpgsql VOLATILE
COST 1;
ALTER FUNCTION insert_tcexam_group(text, character varying, character varying, character varying)
OWNER TO postgres;
-- insert_tcexam_user
CREATE OR REPLACE FUNCTION insert_tcexam_user(xmlbody text, pgroupid character varying, pappointmentid character varying)
RETURNS void AS
$BODY$
DECLARE
login character varying;
email character varying;
firstname character varying;
lastname character varying;
uservo xml;
BEGIN
uservo = xmlbody::xml;
SELECT (xpath('/userVO/login/text()', uservo))[1] into login;
SELECT (xpath('/userVO/email/text()', uservo))[1] into email;
SELECT (xpath('/userVO/firstName/text()', uservo))[1] into firstname;
SELECT (xpath('/userVO/lastName/text()', uservo))[1] into lastname;
IF NOT EXISTS(SELECT user_name from tce_users where user_name = login )
THEN
INSERT INTO tce_users (user_name, user_email, user_firstname, user_lastname, user_level, user_regdate, user_password, user_ip)
VALUES (login,email,firstname,lastname, 1, now(), 'no£password', '127.0.0.1') ;
END IF;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 100;
ALTER FUNCTION insert_tcexam_user(text, character varying, character varying)
OWNER TO postgres;
-- remove_tcexam_user_from_group
CREATE OR REPLACE FUNCTION remove_tcexam_user_from_group(xmlbody text, pgroupid character varying, pappointmentid character varying)
RETURNS void AS
$BODY$
DECLARE
login character varying;
userid integer;
groupid integer;
uservo xml;
BEGIN
uservo = xmlbody::xml;
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 = pgroupid || ':' || pappointmentid;
UPDATE tce_users SET user_level = 0 WHERE user_id = userid;
DELETE FROM tce_usrgroups WHERE usrgrp_user_id = userid AND usrgrp_group_id = groupid;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 1;
ALTER FUNCTION remove_tcexam_user_from_group(text, character varying, character varying)
OWNER TO postgres;
-- update_tcexam_group
CREATE OR REPLACE FUNCTION update_tcexam_group(pgroupid character varying, pappointmentid character varying, pgroupname character varying)
RETURNS void AS
$BODY$
DECLARE
theKey character varying;
BEGIN
theKey = pgroupid || ':' || pappointmentid;
IF (SELECT group_name FROM tce_user_groups WHERE external_id = theKey) != pgroupname THEN
UPDATE tce_user_groups set group_name = pgroupname WHERE external_id = theKey;
END IF;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 1;
ALTER FUNCTION update_tcexam_group(character varying, character varying, character varying)
OWNER TO postgres;
-- update_tcexam_user
CREATE OR REPLACE FUNCTION update_tcexam_user(xmlbody text, pgroupid character varying, pappointmentid character varying)
RETURNS void AS
$BODY$
DECLARE
login character varying;
email character varying;
firstname character varying;
lastname character varying;
uservo xml;
BEGIN
uservo = xmlbody::xml;
SELECT (xpath('/userVO/login/text()', uservo))[1] into login;
SELECT (xpath('/userVO/email/text()', uservo))[1] into email;
SELECT (xpath('/userVO/firstName/text()', uservo))[1] into firstname;
SELECT (xpath('/userVO/lastName/text()', uservo))[1] into lastname;
IF (SELECT user_email FROM tce_users WHERE user_name = login) != email
THEN
UPDATE tce_users SET user_email = email WHERE user_name = login;
END IF;
IF (SELECT user_firstname FROM tce_users WHERE user_name = login) != firstname
THEN
UPDATE tce_users SET user_firstname = firstname WHERE user_name = login;
END IF;
IF (SELECT user_lastname FROM tce_users WHERE user_name = login) != lastname
THEN
UPDATE tce_users SET user_lastname = lastname WHERE user_name = login;
END IF;
END;
$BODY$
LANGUAGE plpgsql VOLATILE
COST 1;
ALTER FUNCTION update_tcexam_user(text, character varying, character varying)
OWNER TO postgres;
\ No newline at end of file
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