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
|
CREATE SCHEMA frange;
SET search_path = frange,public,pg_catalog;
CREATE TABLE featuregroup (
featuregroup_id serial not null,
primary key (featuregroup_id),
subject_id int not null,
foreign key (subject_id) references feature (feature_id) on delete cascade INITIALLY DEFERRED,
object_id int not null,
foreign key (object_id) references feature (feature_id) on delete cascade INITIALLY DEFERRED,
group_id int not null,
foreign key (group_id) references feature (feature_id) on delete cascade INITIALLY DEFERRED,
srcfeature_id int null,
foreign key (srcfeature_id) references feature (feature_id) on delete cascade INITIALLY DEFERRED,
fmin int null,
fmax int null,
strand int null,
is_root int not null default 0,
constraint featuregroup_c1 unique (subject_id,object_id,group_id,srcfeature_id,fmin,fmax,strand)
);
CREATE INDEX featuregroup_idx1 ON featuregroup (subject_id);
CREATE INDEX featuregroup_idx2 ON featuregroup (object_id);
CREATE INDEX featuregroup_idx3 ON featuregroup (group_id);
CREATE INDEX featuregroup_idx4 ON featuregroup (srcfeature_id);
CREATE INDEX featuregroup_idx5 ON featuregroup (strand);
CREATE INDEX featuregroup_idx6 ON featuregroup (is_root);
CREATE OR REPLACE FUNCTION groupoverlaps(int4, int4, varchar) RETURNS setof featuregroup AS '
SELECT g2.*
FROM featuregroup g1,
featuregroup g2
WHERE g1.is_root = 1
AND ( g1.srcfeature_id = g2.srcfeature_id OR g2.srcfeature_id IS NULL )
AND g1.group_id = g2.group_id
AND g1.srcfeature_id = (SELECT feature_id FROM feature WHERE uniquename = $3)
AND boxquery($1, $2) @ boxrange(g1.fmin,g2.fmax)
' LANGUAGE 'sql';
CREATE OR REPLACE FUNCTION groupcontains(int4, int4, varchar) RETURNS setof featuregroup AS '
SELECT *
FROM groupoverlaps($1,$2,$3)
WHERE fmin <= $1 AND fmax >= $2
' LANGUAGE 'sql';
CREATE OR REPLACE FUNCTION groupinside(int4, int4, varchar) RETURNS setof featuregroup AS '
SELECT *
FROM groupoverlaps($1,$2,$3)
WHERE fmin >= $1 AND fmax <= $2
' LANGUAGE 'sql';
CREATE OR REPLACE FUNCTION groupidentical(int4, int4, varchar) RETURNS setof featuregroup AS '
SELECT *
FROM groupoverlaps($1,$2,$3)
WHERE fmin = $1 AND fmax = $2
' LANGUAGE 'sql';
CREATE OR REPLACE FUNCTION groupoverlaps(int4, int4) RETURNS setof featuregroup AS '
SELECT *
FROM featuregroup
WHERE is_root = 1
AND boxquery($1, $2) @ boxrange(fmin,fmax)
' LANGUAGE 'sql';
CREATE OR REPLACE FUNCTION groupoverlaps(_int4, _int4, _varchar) RETURNS setof featuregroup AS '
DECLARE
mins alias for $1;
maxs alias for $2;
srcs alias for $3;
f featuregroup%ROWTYPE;
i int;
s int;
BEGIN
i := 1;
FOR i in array_lower( mins, 1 ) .. array_upper( mins, 1 ) LOOP
SELECT INTO s feature_id FROM feature WHERE uniquename = srcs[i];
FOR f IN
SELECT *
FROM featuregroup WHERE group_id IN (
SELECT group_id FROM featuregroup
WHERE (srcfeature_id = s OR srcfeature_id IS NULL)
AND group_id IN (
SELECT group_id FROM groupoverlaps( mins[i], maxs[i] )
WHERE srcfeature_id = s
)
)
LOOP
RETURN NEXT f;
END LOOP;
END LOOP;
RETURN;
END;
' LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION groupcontains(_int4, _int4, _varchar) RETURNS setof featuregroup AS '
DECLARE
mins alias for $1;
maxs alias for $2;
srcs alias for $3;
f featuregroup%ROWTYPE;
i int;
s int;
BEGIN
i := 1;
FOR i in array_lower( mins, 1 ) .. array_upper( mins, 1 ) LOOP
SELECT INTO s feature_id FROM feature WHERE uniquename = srcs[i];
FOR f IN
SELECT *
FROM featuregroup WHERE group_id IN (
SELECT group_id FROM featuregroup
WHERE (srcfeature_id = s OR srcfeature_id IS NULL)
AND fmin <= mins[i]
AND fmax >= maxs[i]
AND group_id IN (
SELECT group_id FROM groupoverlaps( mins[i], maxs[i] )
WHERE srcfeature_id = s
)
)
LOOP
RETURN NEXT f;
END LOOP;
END LOOP;
RETURN;
END;
' LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION groupinside(_int4, _int4, _varchar) RETURNS setof featuregroup AS '
DECLARE
mins alias for $1;
maxs alias for $2;
srcs alias for $3;
f featuregroup%ROWTYPE;
i int;
s int;
BEGIN
i := 1;
FOR i in array_lower( mins, 1 ) .. array_upper( mins, 1 ) LOOP
SELECT INTO s feature_id FROM feature WHERE uniquename = srcs[i];
FOR f IN
SELECT *
FROM featuregroup WHERE group_id IN (
SELECT group_id FROM featuregroup
WHERE (srcfeature_id = s OR srcfeature_id IS NULL)
AND fmin >= mins[i]
AND fmax <= maxs[i]
AND group_id IN (
SELECT group_id FROM groupoverlaps( mins[i], maxs[i] )
WHERE srcfeature_id = s
)
)
LOOP
RETURN NEXT f;
END LOOP;
END LOOP;
RETURN;
END;
' LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION groupidentical(_int4, _int4, _varchar) RETURNS setof featuregroup AS '
DECLARE
mins alias for $1;
maxs alias for $2;
srcs alias for $3;
f featuregroup%ROWTYPE;
i int;
s int;
BEGIN
i := 1;
FOR i in array_lower( mins, 1 ) .. array_upper( mins, 1 ) LOOP
SELECT INTO s feature_id FROM feature WHERE uniquename = srcs[i];
FOR f IN
SELECT *
FROM featuregroup WHERE group_id IN (
SELECT group_id FROM featuregroup
WHERE (srcfeature_id = s OR srcfeature_id IS NULL)
AND fmin = mins[i]
AND fmax = maxs[i]
AND group_id IN (
SELECT group_id FROM groupoverlaps( mins[i], maxs[i] )
WHERE srcfeature_id = s
)
)
LOOP
RETURN NEXT f;
END LOOP;
END LOOP;
RETURN;
END;
' LANGUAGE 'plpgsql';
--functional index that depends on the above functions
CREATE INDEX bingroup_boxrange ON featuregroup USING RTREE (boxrange(fmin, fmax)) WHERE is_root = 1;
CREATE OR REPLACE FUNCTION _fill_featuregroup(INTEGER, INTEGER) RETURNS INTEGER AS '
DECLARE
groupid alias for $1;
parentid alias for $2;
g featuregroup%ROWTYPE;
BEGIN
FOR g IN
SELECT DISTINCT 0, fr.subject_id, fr.object_id, groupid, fl.srcfeature_id, fl.fmin, fl.fmax, fl.strand, 0
FROM feature_relationship AS fr,
featureloc AS fl
WHERE fr.object_id = parentid
AND fr.subject_id = fl.feature_id
LOOP
INSERT INTO featuregroup
(subject_id, object_id, group_id, srcfeature_id, fmin, fmax, strand, is_root)
VALUES
(g.subject_id, g.object_id, g.group_id, g.srcfeature_id, g.fmin, g.fmax, g.strand, 0);
PERFORM _fill_featuregroup(groupid,g.subject_id);
END LOOP;
RETURN 1;
END;
' LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION fill_featuregroup() RETURNS INTEGER AS '
DECLARE
p featuregroup%ROWTYPE;
l featureloc%ROWTYPE;
isa int;
c int;
BEGIN
TRUNCATE featuregroup;
SELECT INTO isa cvterm_id FROM cvterm WHERE (name = ''isa'' OR name = ''is_a'');
-- Recursion is the biggest performance killer for this function.
-- We can dodge the first round of recursion using the "fr1 / GROUP BY" approach.
-- Luckily, most feature graphs are only 2 levels deep, so most recursion is
-- avoidable.
RAISE NOTICE ''Loading root and singleton features.'';
FOR p IN
SELECT DISTINCT 0, f.feature_id, f.feature_id, f.feature_id, srcfeature_id, fmin, fmax, strand, 1
FROM feature AS f
LEFT JOIN feature_relationship ON (f.feature_id = object_id)
LEFT JOIN featureloc ON (f.feature_id = featureloc.feature_id)
WHERE f.feature_id NOT IN ( SELECT subject_id FROM feature_relationship )
AND srcfeature_id IS NOT NULL
LOOP
INSERT INTO featuregroup
(subject_id, object_id, group_id, srcfeature_id, fmin, fmax, strand, is_root)
VALUES
(p.object_id, p.object_id, p.object_id, p.srcfeature_id, p.fmin, p.fmax, p.strand, 1);
END LOOP;
RAISE NOTICE ''Loading child features. If your database contains grandchild'';
RAISE NOTICE ''features, they will be loaded recursively and may take a long time.'';
FOR p IN
SELECT DISTINCT 0, fr0.subject_id, fr0.object_id, fr0.object_id, fl.srcfeature_id, fl.fmin, fl.fmax, fl.strand, count(fr1.subject_id)
FROM feature_relationship AS fr0
LEFT JOIN feature_relationship AS fr1 ON ( fr0.subject_id = fr1.object_id),
featureloc AS fl
WHERE fr0.subject_id = fl.feature_id
AND fr0.object_id IN (
SELECT f.feature_id
FROM feature AS f
LEFT JOIN feature_relationship ON (f.feature_id = object_id)
LEFT JOIN featureloc ON (f.feature_id = featureloc.feature_id)
WHERE f.feature_id NOT IN ( SELECT subject_id FROM feature_relationship )
AND f.feature_id IN ( SELECT object_id FROM feature_relationship )
AND srcfeature_id IS NOT NULL
)
GROUP BY fr0.subject_id, fr0.object_id, fl.srcfeature_id, fl.fmin, fl.fmax, fl.strand
LOOP
INSERT INTO featuregroup
(subject_id, object_id, group_id, srcfeature_id, fmin, fmax, strand, is_root)
VALUES
(p.subject_id, p.object_id, p.object_id, p.srcfeature_id, p.fmin, p.fmax, p.strand, 0);
IF ( p.is_root > 0 ) THEN
PERFORM _fill_featuregroup(p.subject_id,p.subject_id);
END IF;
END LOOP;
RETURN 1;
END;
' LANGUAGE 'plpgsql';
SET search_path = public,pg_catalog;
|