1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85
|
--- example: select * from fill_cvtermpath(7); where 7 is cv_id for an ontology
--- fill path from the node to its children and their children
CREATE OR REPLACE FUNCTION _fill_cvtermpath4node(INTEGER, INTEGER, INTEGER, INTEGER, INTEGER) RETURNS INTEGER AS
'
DECLARE
origin alias for $1;
child_id alias for $2;
cvid alias for $3;
typeid alias for $4;
depth alias for $5;
cterm cvterm_relationship%ROWTYPE;
exist_c int;
BEGIN
--- RAISE NOTICE ''depth=% root=%'', depth,child_id;
--- not check type_id as it may be null and not very meaningful in cvtermpath when pathdistance > 1
SELECT INTO exist_c count(*) FROM cvtermpath WHERE cv_id = cvid AND object_id = origin AND subject_id = child_id AND pathdistance = depth;
IF (exist_c = 0) THEN
INSERT INTO cvtermpath (object_id, subject_id, cv_id, type_id, pathdistance) VALUES(origin, child_id, cvid, typeid, depth);
END IF;
FOR cterm IN SELECT * FROM cvterm_relationship WHERE object_id = child_id LOOP
PERFORM _fill_cvtermpath4node(origin, cterm.subject_id, cvid, cterm.type_id, depth+1);
END LOOP;
RETURN 1;
END;
'
LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION _fill_cvtermpath4root(INTEGER, INTEGER) RETURNS INTEGER AS
'
DECLARE
rootid alias for $1;
cvid alias for $2;
ttype int;
cterm cvterm_relationship%ROWTYPE;
child cvterm_relationship%ROWTYPE;
BEGIN
SELECT INTO ttype cvterm_id FROM cvterm WHERE (name = ''isa'' OR name = ''is_a'');
PERFORM _fill_cvtermpath4node(rootid, rootid, cvid, ttype, 0);
FOR cterm IN SELECT * FROM cvterm_relationship WHERE object_id = rootid LOOP
PERFORM _fill_cvtermpath4root(cterm.subject_id, cvid);
-- RAISE NOTICE ''DONE for term, %'', cterm.subject_id;
END LOOP;
RETURN 1;
END;
'
LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION fill_cvtermpath(INTEGER) RETURNS INTEGER AS
'
DECLARE
cvid alias for $1;
root cvterm%ROWTYPE;
BEGIN
DELETE FROM cvtermpath WHERE cv_id = cvid;
FOR root IN SELECT DISTINCT t.* from cvterm t LEFT JOIN cvterm_relationship r ON (t.cvterm_id = r.subject_id) INNER JOIN cvterm_relationship r2 ON (t.cvterm_id = r2.object_id) WHERE t.cv_id = cvid AND r.subject_id is null LOOP
PERFORM _fill_cvtermpath4root(root.cvterm_id, root.cv_id);
END LOOP;
RETURN 1;
END;
'
LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION fill_cvtermpath(cv.name%TYPE) RETURNS INTEGER AS
'
DECLARE
cvname alias for $1;
cv_id int;
rtn int;
BEGIN
SELECT INTO cv_id cv.cv_id from cv WHERE cv.name = cvname;
SELECT INTO rtn fill_cvtermpath(cv_id);
RETURN rtn;
END;
'
LANGUAGE 'plpgsql';
|