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 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375 376 377 378 379 380 381 382 383 384 385 386 387 388 389 390 391 392 393 394 395 396 397 398 399 400 401 402 403 404 405 406 407 408 409 410 411 412 413 414 415 416 417 418 419 420 421 422 423 424 425 426 427 428 429
|
---bad precedence: change customed type name
---drop here to remove old function
--DROP TYPE feature_by_cvt_type CASCADE;
--DROP TYPE fxgsfids_type CASCADE;
--DROP TYPE feature_by_fx_type CASCADE;
CREATE TYPE feature_by_fx_type AS (
feature_id INTEGER,
depth INT
);
CREATE OR REPLACE FUNCTION get_sub_feature_ids(text) RETURNS SETOF feature_by_fx_type AS
'
DECLARE
sql alias for $1;
myrc feature_by_fx_type%ROWTYPE;
myrc2 feature_by_fx_type%ROWTYPE;
BEGIN
FOR myrc IN EXECUTE sql LOOP
FOR myrc2 IN SELECT * FROM get_sub_feature_ids(myrc.feature_id) LOOP
RETURN NEXT myrc2;
END LOOP;
END LOOP;
RETURN;
END;
'
LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION get_up_feature_ids(text) RETURNS SETOF feature_by_fx_type AS
'
DECLARE
sql alias for $1;
myrc feature_by_fx_type%ROWTYPE;
myrc2 feature_by_fx_type%ROWTYPE;
BEGIN
FOR myrc IN EXECUTE sql LOOP
FOR myrc2 IN SELECT * FROM get_up_feature_ids(myrc.feature_id) LOOP
RETURN NEXT myrc2;
END LOOP;
END LOOP;
RETURN;
END;
'
LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION get_feature_ids(text) RETURNS SETOF feature_by_fx_type AS
'
DECLARE
sql alias for $1;
myrc feature_by_fx_type%ROWTYPE;
myrc2 feature_by_fx_type%ROWTYPE;
myrc3 feature_by_fx_type%ROWTYPE;
BEGIN
FOR myrc IN EXECUTE sql LOOP
RETURN NEXT myrc;
FOR myrc2 IN SELECT * FROM get_up_feature_ids(myrc.feature_id) LOOP
RETURN NEXT myrc2;
END LOOP;
FOR myrc3 IN SELECT * FROM get_sub_feature_ids(myrc.feature_id) LOOP
RETURN NEXT myrc3;
END LOOP;
END LOOP;
RETURN;
END;
'
LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION get_sub_feature_ids(integer) RETURNS SETOF feature_by_fx_type AS
'
DECLARE
root alias for $1;
myrc feature_by_fx_type%ROWTYPE;
myrc2 feature_by_fx_type%ROWTYPE;
BEGIN
FOR myrc IN SELECT DISTINCT subject_id AS feature_id FROM feature_relationship WHERE object_id = root LOOP
RETURN NEXT myrc;
FOR myrc2 IN SELECT * FROM get_sub_feature_ids(myrc.feature_id) LOOP
RETURN NEXT myrc2;
END LOOP;
END LOOP;
RETURN;
END;
'
LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION get_up_feature_ids(integer) RETURNS SETOF feature_by_fx_type AS
'
DECLARE
leaf alias for $1;
myrc feature_by_fx_type%ROWTYPE;
myrc2 feature_by_fx_type%ROWTYPE;
BEGIN
FOR myrc IN SELECT DISTINCT object_id AS feature_id FROM feature_relationship WHERE subject_id = leaf LOOP
RETURN NEXT myrc;
FOR myrc2 IN SELECT * FROM get_up_feature_ids(myrc.feature_id) LOOP
RETURN NEXT myrc2;
END LOOP;
END LOOP;
RETURN;
END;
'
LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION get_sub_feature_ids(integer, integer) RETURNS SETOF feature_by_fx_type AS
'
DECLARE
root alias for $1;
depth alias for $2;
myrc feature_by_fx_type%ROWTYPE;
myrc2 feature_by_fx_type%ROWTYPE;
BEGIN
FOR myrc IN SELECT DISTINCT subject_id AS feature_id, depth FROM feature_relationship WHERE object_id = root LOOP
RETURN NEXT myrc;
FOR myrc2 IN SELECT * FROM get_sub_feature_ids(myrc.feature_id,depth+1) LOOP
RETURN NEXT myrc2;
END LOOP;
END LOOP;
RETURN;
END;
'
LANGUAGE 'plpgsql';
--- depth is reversed and meanless when union with results from get_sub_feature_ids
CREATE OR REPLACE FUNCTION get_up_feature_ids(integer, integer) RETURNS SETOF feature_by_fx_type AS
'
DECLARE
leaf alias for $1;
depth alias for $2;
myrc feature_by_fx_type%ROWTYPE;
myrc2 feature_by_fx_type%ROWTYPE;
BEGIN
FOR myrc IN SELECT DISTINCT object_id AS feature_id, depth FROM feature_relationship WHERE subject_id = leaf LOOP
RETURN NEXT myrc;
FOR myrc2 IN SELECT * FROM get_up_feature_ids(myrc.feature_id,depth+1) LOOP
RETURN NEXT myrc2;
END LOOP;
END LOOP;
RETURN;
END;
'
LANGUAGE 'plpgsql';
--- children feature ids only (not include itself--parent) for SO type and range (src)
CREATE OR REPLACE FUNCTION get_sub_feature_ids_by_type_src(cvterm.name%TYPE,feature.uniquename%TYPE,char(1)) RETURNS SETOF feature_by_fx_type AS
'
DECLARE
gtype alias for $1;
src alias for $2;
is_an alias for $3;
query text;
myrc feature_by_fx_type%ROWTYPE;
myrc2 feature_by_fx_type%ROWTYPE;
BEGIN
query := ''SELECT DISTINCT f.feature_id FROM feature f INNER join cvterm t ON (f.type_id = t.cvterm_id)
INNER join featureloc fl
ON (f.feature_id = fl.feature_id) INNER join feature src ON (src.feature_id = fl.srcfeature_id)
WHERE t.name = '' || quote_literal(gtype) || '' AND src.uniquename = '' || quote_literal(src)
|| '' AND f.is_analysis = '' || quote_literal(is_an) || '';'';
IF (STRPOS(gtype, ''%'') > 0) THEN
query := ''SELECT DISTINCT f.feature_id FROM feature f INNER join cvterm t ON (f.type_id = t.cvterm_id)
INNER join featureloc fl
ON (f.feature_id = fl.feature_id) INNER join feature src ON (src.feature_id = fl.srcfeature_id)
WHERE t.name like '' || quote_literal(gtype) || '' AND src.uniquename = '' || quote_literal(src)
|| '' AND f.is_analysis = '' || quote_literal(is_an) || '';'';
END IF;
FOR myrc IN SELECT * FROM get_sub_feature_ids(query) LOOP
RETURN NEXT myrc;
END LOOP;
RETURN;
END;
'
LANGUAGE 'plpgsql';
--- by SO type, usefull for tRNA, ncRNA, etc
CREATE OR REPLACE FUNCTION get_feature_ids_by_type(cvterm.name%TYPE, char(1)) RETURNS SETOF feature_by_fx_type AS
'
DECLARE
gtype alias for $1;
is_an alias for $2;
query TEXT;
myrc feature_by_fx_type%ROWTYPE;
myrc2 feature_by_fx_type%ROWTYPE;
BEGIN
query := ''SELECT DISTINCT f.feature_id
FROM feature f, cvterm t WHERE t.cvterm_id = f.type_id AND t.name = '' || quote_literal(gtype) ||
'' AND f.is_analysis = '' || quote_literal(is_an) || '';'';
IF (STRPOS(gtype, ''%'') > 0) THEN
query := ''SELECT DISTINCT f.feature_id
FROM feature f, cvterm t WHERE t.cvterm_id = f.type_id AND t.name like ''
|| quote_literal(gtype) || '' AND f.is_analysis = '' || quote_literal(is_an) || '';'';
END IF;
FOR myrc IN SELECT * FROM get_feature_ids(query) LOOP
RETURN NEXT myrc;
END LOOP;
RETURN;
END;
'
LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION get_feature_ids_by_type_src(cvterm.name%TYPE, feature.uniquename%TYPE, char(1)) RETURNS SETOF feature_by_fx_type AS
'
DECLARE
gtype alias for $1;
src alias for $2;
is_an alias for $3;
query TEXT;
myrc feature_by_fx_type%ROWTYPE;
myrc2 feature_by_fx_type%ROWTYPE;
BEGIN
query := ''SELECT DISTINCT f.feature_id
FROM feature f INNER join cvterm t ON (f.type_id = t.cvterm_id) INNER join featureloc fl
ON (f.feature_id = fl.feature_id) INNER join feature src ON (src.feature_id = fl.srcfeature_id)
WHERE t.name = '' || quote_literal(gtype) || '' AND src.uniquename = '' || quote_literal(src)
|| '' AND f.is_analysis = '' || quote_literal(is_an) || '';'';
IF (STRPOS(gtype, ''%'') > 0) THEN
query := ''SELECT DISTINCT f.feature_id
FROM feature f INNER join cvterm t ON (f.type_id = t.cvterm_id) INNER join featureloc fl
ON (f.feature_id = fl.feature_id) INNER join feature src ON (src.feature_id = fl.srcfeature_id)
WHERE t.name like '' || quote_literal(gtype) || '' AND src.uniquename = '' || quote_literal(src)
|| '' AND f.is_analysis = '' || quote_literal(is_an) || '';'';
END IF;
FOR myrc IN SELECT * FROM get_feature_ids(query) LOOP
RETURN NEXT myrc;
END LOOP;
RETURN;
END;
'
LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION get_feature_ids_by_type_name(cvterm.name%TYPE, feature.uniquename%TYPE, char(1)) RETURNS SETOF feature_by_fx_type AS
'
DECLARE
gtype alias for $1;
name alias for $2;
is_an alias for $3;
query TEXT;
myrc feature_by_fx_type%ROWTYPE;
myrc2 feature_by_fx_type%ROWTYPE;
BEGIN
query := ''SELECT DISTINCT f.feature_id
FROM feature f INNER join cvterm t ON (f.type_id = t.cvterm_id)
WHERE t.name = '' || quote_literal(gtype) || '' AND (f.uniquename = '' || quote_literal(name)
|| '' OR f.name = '' || quote_literal(name) || '') AND f.is_analysis = '' || quote_literal(is_an) || '';'';
IF (STRPOS(name, ''%'') > 0) THEN
query := ''SELECT DISTINCT f.feature_id
FROM feature f INNER join cvterm t ON (f.type_id = t.cvterm_id)
WHERE t.name = '' || quote_literal(gtype) || '' AND (f.uniquename like '' || quote_literal(name)
|| '' OR f.name like '' || quote_literal(name) || '') AND f.is_analysis = '' || quote_literal(is_an) || '';'';
END IF;
FOR myrc IN SELECT * FROM get_feature_ids(query) LOOP
RETURN NEXT myrc;
END LOOP;
RETURN;
END;
'
LANGUAGE 'plpgsql';
--- get all feature ids (including children) for feature that has an ontology term (say GO function)
CREATE OR REPLACE FUNCTION get_feature_ids_by_ont(cv.name%TYPE,cvterm.name%TYPE) RETURNS SETOF feature_by_fx_type AS
'
DECLARE
aspect alias for $1;
term alias for $2;
query TEXT;
myrc feature_by_fx_type%ROWTYPE;
myrc2 feature_by_fx_type%ROWTYPE;
BEGIN
query := ''SELECT DISTINCT fcvt.feature_id
FROM feature_cvterm fcvt, cv, cvterm t WHERE cv.cv_id = t.cv_id AND
t.cvterm_id = fcvt.cvterm_id AND cv.name = '' || quote_literal(aspect) ||
'' AND t.name = '' || quote_literal(term) || '';'';
IF (STRPOS(term, ''%'') > 0) THEN
query := ''SELECT DISTINCT fcvt.feature_id
FROM feature_cvterm fcvt, cv, cvterm t WHERE cv.cv_id = t.cv_id AND
t.cvterm_id = fcvt.cvterm_id AND cv.name = '' || quote_literal(aspect) ||
'' AND t.name like '' || quote_literal(term) || '';'';
END IF;
FOR myrc IN SELECT * FROM get_feature_ids(query) LOOP
RETURN NEXT myrc;
END LOOP;
RETURN;
END;
'
LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION get_feature_ids_by_ont_root(cv.name%TYPE,cvterm.name%TYPE) RETURNS SETOF feature_by_fx_type AS
'
DECLARE
aspect alias for $1;
term alias for $2;
query TEXT;
subquery TEXT;
myrc feature_by_fx_type%ROWTYPE;
myrc2 feature_by_fx_type%ROWTYPE;
BEGIN
subquery := ''SELECT t.cvterm_id FROM cv, cvterm t WHERE cv.cv_id = t.cv_id
AND cv.name = '' || quote_literal(aspect) || '' AND t.name = '' || quote_literal(term) || '';'';
IF (STRPOS(term, ''%'') > 0) THEN
subquery := ''SELECT t.cvterm_id FROM cv, cvterm t WHERE cv.cv_id = t.cv_id
AND cv.name = '' || quote_literal(aspect) || '' AND t.name like '' || quote_literal(term) || '';'';
END IF;
query := ''SELECT DISTINCT fcvt.feature_id
FROM feature_cvterm fcvt INNER JOIN (SELECT cvterm_id FROM get_it_sub_cvterm_ids('' || quote_literal(subquery) || '')) AS ont ON (fcvt.cvterm_id = ont.cvterm_id);'';
FOR myrc IN SELECT * FROM get_feature_ids(query) LOOP
RETURN NEXT myrc;
END LOOP;
RETURN;
END;
'
LANGUAGE 'plpgsql';
--- get all feature ids (including children) for feature with the property (type, val)
CREATE OR REPLACE FUNCTION get_feature_ids_by_property(cvterm.name%TYPE,varchar) RETURNS SETOF feature_by_fx_type AS
'
DECLARE
p_type alias for $1;
p_val alias for $2;
query TEXT;
myrc feature_by_fx_type%ROWTYPE;
myrc2 feature_by_fx_type%ROWTYPE;
BEGIN
query := ''SELECT DISTINCT fprop.feature_id
FROM featureprop fprop, cvterm t WHERE t.cvterm_id = fprop.type_id AND t.name = '' ||
quote_literal(p_type) || '' AND fprop.value = '' || quote_literal(p_val) || '';'';
IF (STRPOS(p_val, ''%'') > 0) THEN
query := ''SELECT DISTINCT fprop.feature_id
FROM featureprop fprop, cvterm t WHERE t.cvterm_id = fprop.type_id AND t.name = '' ||
quote_literal(p_type) || '' AND fprop.value like '' || quote_literal(p_val) || '';'';
END IF;
FOR myrc IN SELECT * FROM get_feature_ids(query) LOOP
RETURN NEXT myrc;
END LOOP;
RETURN;
END;
'
LANGUAGE 'plpgsql';
--- get all feature ids (including children) for feature with the property val
CREATE OR REPLACE FUNCTION get_feature_ids_by_propval(varchar) RETURNS SETOF feature_by_fx_type AS
'
DECLARE
p_val alias for $1;
query TEXT;
myrc feature_by_fx_type%ROWTYPE;
myrc2 feature_by_fx_type%ROWTYPE;
BEGIN
query := ''SELECT DISTINCT fprop.feature_id
FROM featureprop fprop WHERE fprop.value = '' || quote_literal(p_val) || '';'';
IF (STRPOS(p_val, ''%'') > 0) THEN
query := ''SELECT DISTINCT fprop.feature_id
FROM featureprop fprop WHERE fprop.value like '' || quote_literal(p_val) || '';'';
END IF;
FOR myrc IN SELECT * FROM get_feature_ids(query) LOOP
RETURN NEXT myrc;
END LOOP;
RETURN;
END;
'
LANGUAGE 'plpgsql';
---4 args: ptype, ctype, count, operator (valid SQL number comparison operator), and is_analysis
---get feature ids for any node with type = ptype whose child node type = ctype
---and child node feature count comparing (using operator) to ccount
CREATE OR REPLACE FUNCTION get_feature_ids_by_child_count(cvterm.name%TYPE, cvterm.name%TYPE, INTEGER, varchar, char(1)) RETURNS SETOF feature_by_fx_type AS
'
DECLARE
ptype alias for $1;
ctype alias for $2;
ccount alias for $3;
operator alias for $4;
is_an alias for $5;
query TEXT;
myrc feature_by_fx_type%ROWTYPE;
myrc2 feature_by_fx_type %ROWTYPE;
BEGIN
query := ''SELECT DISTINCT f.feature_id
FROM feature f INNER join (select count(*) as c, p.feature_id FROM feature p
INNER join cvterm pt ON (p.type_id = pt.cvterm_id) INNER join feature_relationship fr
ON (p.feature_id = fr.object_id) INNER join feature c ON (c.feature_id = fr.subject_id)
INNER join cvterm ct ON (c.type_id = ct.cvterm_id)
WHERE pt.name = '' || quote_literal(ptype) || '' AND ct.name = '' || quote_literal(ctype)
|| '' AND p.is_analysis = '' || quote_literal(is_an) || '' group by p.feature_id) as cq
ON (cq.feature_id = f.feature_id) WHERE cq.c '' || operator || ccount || '';'';
---RAISE NOTICE ''%'', query;
FOR myrc IN SELECT * FROM get_feature_ids(query) LOOP
RETURN NEXT myrc;
END LOOP;
RETURN;
END;
'
LANGUAGE 'plpgsql';
|