back to first page[..][[BR]] back to ["RHT"][[BR]] {{{ #!sql -- script de calcul des distances sources set search_path to rht,public; select cast(ltree2text(subltree(chemin,0,1)) as integer) from rht_topology limit 10 /* AJOUT D'UN INDEX ltree supports several types of indexes that can speed up the indicated operators: B-tree index over ltree: <, <=, =, >=, > GiST index over ltree: <, <=, =, >=, >, @>, <@, @, ~, ? */ CREATE INDEX chemin_btee_index ON rht.rht_topology USING btree(chemin); --27688 ms VACUUM ANALYSE rht.rht_topology; CREATE INDEX chemin_gist_index ON rht.rht_topology USING GIST (chemin); -- fait planter mon serveur.... SELECT * from rht.rht_topology where chemin <@ '212340'; -- tronçon source de la Vilaine -- 2360 SELECT chemin from rht.rht_topology where chemin <@ '212340' limit 1 -- La distance source est la distance mer maximale de tous les chemins possibles en ne prenant que le dernier tronçon du chemin. Select max(dmer) from rht.rht_topology where id_drain in ( Select cast(ltree2text(subpath(chemin, -1, 1))as integer) as chenin_id_drain from rht.rht_topology where chemin <@ '212340'); -- fonction pour renvoyer les distances source DROP FUNCTION IF EXISTS rht.distance_source(); CREATE OR REPLACE FUNCTION rht.distance_source() RETURNS integer AS $$ DECLARE id_drains RECORD; nbligne integer; BEGIN nbligne:=1; DROP TABLE IF EXISTS rht.distance_mer; CREATE TABLE rht.distance_mer (id_drain integer,distance_mer numeric); FOR id_drains IN SELECT id_drain FROM rht.rht_topology ORDER BY id_drain LOOP -- pour vérification décommenter ensuite RAISE NOTICE 'distance_source for %', quote_ident(CAST(id_drains.id_drain as text)); EXECUTE 'INSERT INTO rht.distance_mer SELECT MAX(dmer) FROM rht.rht_topology WHERE id_drain IN ( SELECT CAST(ltree2text(subpath(chemin, -1, 1))as integer) FROM rht.rht_topology where chemin <@ text2ltree(cast ('|| id_drains.id_drain || 'as text)) )'; nbligne=nbligne+1; END LOOP; RETURN nbligne; END; $$ LANGUAGE plpgsql; select rht.distance_source(); }}} == utilisation des donnees de parcours == En pratique nous n'aurons probablement besoin que du noeud le plus amont des parcours comme programmé ci dessus. Mais les scripts ci-dessous pourraient s'avérer utiles. [[BR]] Ci dessous la fonction utilise les expressions régulières ltree => vecteur => table {{{ /* regexp_split_to_array(string text, pattern text [, flags text ]) regexp_split_to_array('hello world', E'\\s+') {hello,world} SELECT regexp_split_to_array('hello world', E'\\s+'); SELECT regexp_split_to_array('hello.world', E'\\.+'); */ SELECT regexp_split_to_array(ltree2text(chemin),E'\\.+') from rht.rht_topology where chemin <@ '212340'; /* http://www.pgsql.cz/index.php/PostgreSQL_SQL_Tricks#Array_to_table SELECT (ARRAY[1,3,4,6,7])[idx.n] FROM generate_series(1,7) idx(n); CREATE OR REPLACE FUNCTION unpack(anyarray) RETURNS SETOF anyelement AS $$ SELECT $1[i] FROM generate_series(array_lower($1,1), array_upper($1,1)) g(i); $$ LANGUAGE sql STRICT IMMUTABLE; */ CREATE OR REPLACE FUNCTION unpack(anyarray) RETURNS SETOF anyelement AS $$ SELECT $1[i] FROM generate_series(array_lower($1,1), array_upper($1,1)) g(i); $$ LANGUAGE sql STRICT IMMUTABLE; -- pour convertir un vecteur en table select unpack(vecteurchemin) from (SELECT regexp_split_to_array(ltree2text(chemin),E'\\.+') as vecteurchemin from rht.rht_topology where chemin <@ '212340' limit 1) as sub -- j'avais pas vu il y a déjà une fonction magique unest... select cast(unnest(vecteurchemin) as integer) as chemin_id_drain from (SELECT regexp_split_to_array(ltree2text(chemin),E'\\.+') as vecteurchemin from rht.rht_topology where chemin <@ '212340' limit 1) as sub -- Fonction qui renvoit les identifiants uniques des tronçons en amont d'un ouvrage CREATE OR REPLACE FUNCTION troncons(integer) RETURNS SETOF integer AS $$ select cast(unnest(vecteurchemin) as integer) as chemin_id_drain from (SELECT regexp_split_to_array(ltree2text(chemin),E'\\.+') as vecteurchemin from rht.rht_topology where chemin <@ text2ltree(cast ($1 as text)) limit 1) as sub; $$ LANGUAGE sql STRICT IMMUTABLE; SELECT troncons_amont(212340); -- OK }}}