diff --git a/dev/v3/graf/utils_pgrouting_mapzone_v3.sql b/dev/v3/graf/utils_pgrouting_mapzone_v3.sql new file mode 100644 index 0000000000..1ddad88410 --- /dev/null +++ b/dev/v3/graf/utils_pgrouting_mapzone_v3.sql @@ -0,0 +1,318 @@ +/* +This file is part of Giswater 3 +The program is free software: you can redistribute it and/or modify it under the terms of the GNU General Public License as published by the Free Software Foundation, either version 3 of the License, or (at your option) any later version. +This version of Giswater is provided by Giswater Association + +This code of mapzones have been provide by Claudia Dragoste +*/ + + + +CREATE OR REPLACE FUNCTION amsa_fct_pgr_mapzone(p_mapzone text) + RETURNS text + LANGUAGE plpgsql +AS $function$ + +/* example +SELECT amsa_fct_pgr_mapzone(p_mapzone); p_mapzone in ('sector', 'dma', 'dqa', 'presszone', 'minsector') + +Consulta per visualitzar els arcs amb les seves geometries: + +select a.arc_id, mapzone_id, the_geom from amsa_pgr_arc p +join +(select arc_id, the_geom from arc) a on p.arc_id =a.arc_id::int; + +Consulta per visualitzar els nodes amb les seves geometries : + +select distinct n.node_id, p.mapzone_id , n.the_geom from amsa_pgr_node p +join +(select node_id, the_geom from node) n on p.node_id =n.node_id; + +Consulta per calcular el factor per multiplicar cabal suma/resta cabalimetre en una DMA: + +select n.node_id, n.mapzone_id as mapzone_node, a.mapzone_id as mapzone_arc, +case when n.mapzone_id =a.mapzone_id then 1 +else -1 +end as factor_multiplicar +from amsa_pgr_node n +join amsa_pgr_arc a on n.pgr_node_id in (a.pgr_node_1, a.pgr_node_2) +where n.graph_delimiter ='dma'; + +*/ + +declare + +v_query text; +v_node record; +v_node_id integer=0; +v_i integer; +v_return_text text; +v_mapzone_name text; +v_mapzone_field text; + + + +begin + +--SET search_path = "ws_github_full", public; + +-- no es guarda la geometria, s'ha de fer un join amb la taula node per recuperar-la per els resultats + +v_mapzone_name=lower(p_mapzone); + +if v_mapzone_name not in ('sector', 'dma', 'dqa', 'presszone', 'minsector') then + + v_return_text='ERROR: use one of these options: ''sector'', ''dma'', ''dqa'', ''presszone'', ''minsector'''; +else + -- PART COMUNA MINSECTORS I LA RESTA DE Mapzone + + drop table if exists amsa_pgr_node; + CREATE TABLE amsa_pgr_node ( + pgr_node_id int not null, + node_id varchar(16), + mapzone_id varchar(30) default '0', -- per defecte és Undefined; és text perque el camp "id" per presszone és text + component int, + modif bool default false, -- true si s'han de desconectar els nodes - valvules tancades, inicis de mapzones + graph_delimiter varchar(30), + CONSTRAINT amsa_pgr_node_pkey PRIMARY KEY (pgr_node_id) + ); + CREATE INDEX amsa_pgr_node_node_id ON amsa_pgr_node USING btree (node_id); + + drop table if exists amsa_pgr_arc; + CREATE TABLE amsa_pgr_arc ( + arc_id int not null, + pgr_node_1 int, + pgr_node_2 int, + node_1 varchar(16), + node_2 varchar(16), + mapzone_id varchar(30) default '0', -- per defecte és Undefined; és text perque el camp "id" per presszone és text + component int, + graph_delimiter varchar(30), + cost int default 1, + reverse_cost int default 1, + CONSTRAINT amsa_pgr_arc_pkey PRIMARY KEY (arc_id) + ); + CREATE INDEX amsa_pgr_arc_pgr_node1 ON amsa_pgr_arc USING btree (pgr_node_1); + CREATE INDEX amsa_pgr_arc_pgr_node2 ON amsa_pgr_arc USING btree (pgr_node_2); + CREATE INDEX amsa_pgr_arc_node1 ON amsa_pgr_arc USING btree (node_1); + CREATE INDEX amsa_pgr_arc_node2 ON amsa_pgr_arc USING btree (node_2); + + insert into amsa_pgr_node (pgr_node_id, node_id) + (SELECT node_id::int, node_id + FROM node n + join value_state_type s on s.id =n.state_type + where n.state=1 and s.is_operative =true + ); + + insert into amsa_pgr_arc (arc_id, pgr_node_1,pgr_node_2, node_1, node_2) + (SELECT a.arc_id::int, a.node_1::int, a.node_2::int,a.node_1, a.node_2 + FROM arc a + join value_state_type s on s.id =a.state_type + where a.state=1 and s.is_operative =true + and a.node_1 is not null and a.node_2 is not null -- evita el crash de pgr_connectedComponents + ); + -- FIN PART COMUNA MINSECTORS I LA RESTA DE Mapzone + + -- la opció de minsectors + if v_mapzone_name='minsector' then + update amsa_pgr_node n set modif=true, graph_delimiter='minsector' + from + (select node_id + from node n + join cat_node c on n.nodecat_id=c.id + join cat_feature_node cf on c.nodetype_id =cf.id + where cf.graph_delimiter ='MINSECTOR' + ) s + where n.node_id=s.node_id; + + -- la resta de mapzones + else + + --valvules tancades + update amsa_pgr_node n set modif = true , graph_delimiter='valvula' -- aquest valor a lo millor s'ha de modificar i posar els features que son DELIMITERS DE MINSECTORS + from + (select node_id from man_valve where closed=true ) s + where n.node_id =s.node_id; + + --Mapzone + + v_mapzone_field=v_mapzone_name||'_id'; + + --nodes forceClosed, comportament igual que el de les valvules + + v_query= + 'update amsa_pgr_node n set modif = true, graph_delimiter=''forceClosed'' + from + (SELECT json_array_elements_text((graphconfig->>''forceClosed'')::json) as node_id + from '||v_mapzone_name||' where graphconfig is not null and active is true ) s + where n.node_id =s.node_id'; + execute v_query; + + --nodes inicis de mapzones + + v_query= + 'update amsa_pgr_node n set modif = true, graph_delimiter='''||v_mapzone_name||''', mapzone_id='||v_mapzone_field|| + '::text from + (SELECT '||v_mapzone_field||'::int, (json_array_elements_text((graphconfig->>''use'')::json))::json->>''nodeParent'' as node_id + from '||v_mapzone_name||' where graphconfig is not null and active is true + ) as s + where n.node_id =s.node_id'; + execute v_query; + + --arcs inicis de mapzones + + v_query= + 'update amsa_pgr_arc a set graph_delimiter='''||v_mapzone_name||''', mapzone_id='||v_mapzone_field|| + '::text from + (select s.'||v_mapzone_field||', s.node_id, array_agg(s.to_arc)::int[] as arc_array + FROM + (SELECT '||v_mapzone_field||',(json_array_elements_text((graphconfig->>''use'')::json))::json->>''nodeParent'' as node_id, + json_array_elements_text(((json_array_elements_text((graphconfig->>''use'')::json))::json->>''toArc'')::json) as to_arc + from '||v_mapzone_name||' where graphconfig is not null and active is true + ) as s + group by s.node_id,'||v_mapzone_field||') as s + where s.node_id in (a.node_1, a.node_2) and a.arc_id =any(s.arc_array)'; + execute v_query; + + --nodes "ignore", no s'han de desconnectar + + v_query= + 'update amsa_pgr_node n set modif = true, graph_delimiter=''ignore'' + from + (SELECT json_array_elements_text((graphconfig->>''ignore'')::json) as node_id + from '||v_mapzone_name||' where graphconfig is not null and active is true ) s + where n.node_id =s.node_id'; + execute v_query; + + end if; + + --comença el proces de desconnectar els arcs en els nodes que tenen valor true en el camp "modif"; es fa per elnr d'arcs - 1; + --d'aquesta manera al final hi ha tans nodes com arcs que connecten en el node + + -- PART COMUNA PER MINSECTORS i la resta de mapzones + + EXECUTE 'select max (pgr_node_id) from amsa_pgr_node' + INTO v_node_id; + + FOR v_node IN + select node_id, mapzone_id, graph_delimiter, array_agg(arc_id)::int[] as arc_array, count(arc_id) as arc_count from + (SELECT n.node_id,n.mapzone_id, n.graph_delimiter, a.arc_id + FROM amsa_pgr_node n + join amsa_pgr_arc a on n.node_id in (a.node_1, a.node_2) + where n.modif=true) s + group by node_id,mapzone_id, graph_delimiter + LOOP + FOR i IN 1..v_node.arc_count-1 LOOP + v_node_id=v_node_id+1; + insert into amsa_pgr_node(pgr_node_id, node_id,modif,graph_delimiter, mapzone_id) values (v_node_id, v_node.node_id,true,v_node.graph_delimiter, v_node.mapzone_id); + update amsa_pgr_arc set pgr_node_1=v_node_id where node_1=v_node.node_id and arc_id=v_node.arc_array[i]; + update amsa_pgr_arc set pgr_node_2=v_node_id where node_2=v_node.node_id and arc_id=v_node.arc_array[i]; + END LOOP; + END LOOP; + + drop table if exists amsa_pgr_connectedComponents; + create table amsa_pgr_connectedComponents as + (SELECT * FROM pgr_connectedComponents( + 'SELECT arc_id as id, pgr_node_1 as source, pgr_node_2 as target, cost + FROM amsa_pgr_arc a' + ) + ); + + -- FIN PART COMUNA MINSECTORS I RESTA Mapzone + + -- actualitzar el camp component per els arcs i els nodes + + -- la opció de minsectors - poso per separat tot l'algoritme perquè és molt senzill + + --MINSECTOR + + if v_mapzone_name='minsector' then + + UPDATE amsa_pgr_node n SET component = c.component, mapzone_id=c.component + FROM amsa_pgr_connectedcomponents c + where n.pgr_node_id =c.node; + + UPDATE amsa_pgr_arc a SET component = n.component, mapzone_id=n.component + FROM amsa_pgr_node n + WHERE a.pgr_node_1 = n.pgr_node_id; + + update amsa_pgr_node set mapzone_id ='0' + where graph_delimiter='minsector'; + + -- els connecs agafen el mapzone_id de l'arc al que estan associats + + -- RESTA MAPZONE + else + + UPDATE amsa_pgr_node n SET component = c.component + FROM amsa_pgr_connectedcomponents c + where n.pgr_node_id =c.node; + + UPDATE amsa_pgr_arc a SET component = n.component + FROM amsa_pgr_node n + WHERE a.pgr_node_1 = n.pgr_node_id; + + --ACTUALITZAR EL CAMP MAPZONE_ID primer per arcs i després per nodes; + + --i si el component no té cap mapzone, "mapzone_id" manté el valor que ve per defecte i que és 0 - Undefines + + -- PER ARCS + -- al principi, els arcs que tenen informat mapzone_id són els "to_arc" del "graphconfig" de les taula d'una mapzone; la resta tenen '0' + --es sobrescriuen amb el proces i poden arribar a tenir el valor '-1' Conflict + + --s'actualitzen els arcs de forma masiva, per "component" + + -- si un component té només una mapzone, els arcs d'aquest component tindran el id de la mapzone; + + update amsa_pgr_arc a set mapzone_id=p.mapzone_id + from + (select component,array_to_string(array_agg(distinct mapzone_id),',') as mapzone_id,count(distinct mapzone_id) as mapzone_count + from amsa_pgr_arc + where mapzone_id<>'0' + group by component) as p + where a.component =p.component and p.mapzone_count=1; + + --si el component té més d'una mapzone, els arcs d'aquest component tindran mapzone_id='-1', CONFLICT; + update amsa_pgr_arc a set mapzone_id='-1' + from + (select component,array_to_string(array_agg(distinct mapzone_id),',') as mapzone_id,count(distinct mapzone_id) as mapzone_count + from amsa_pgr_arc + where mapzone_id<>'0' + group by component) as p + where a.component =p.component and p.mapzone_count>1; + + + -- els arcs que no s'han actualitzat anteriorment es queden amb el valor que s'ha posat per defecte ('0' - Undefined) + + -- PER NODES + -- al principi, els nodes que tenen informat mapzone_id són els nodes del "graphconfig" de les taula d'una mapzone (els nodes i els seus clonats que s'han insertat de més) + + -- s'actualitzen els nodes que no tenen informat mapzone_id (són '0', per defecte); + + update amsa_pgr_node n set mapzone_id=a.mapzone_id + from amsa_pgr_arc a + where n.mapzone_id='0' and n.pgr_node_id in (a.pgr_node_1 , a.pgr_node_2 ); + + + -- ara es posen en 0 als que connecten arcs amb mapzone_id diferents + -- molt xulo: si una valvula tancada, per exemple, esta entre sector 2 i sector 3 vol dir que fa frontera, tindrà '0' com mapzone_id; si esta entre -1 i 2 també tindrà 0; + -- en canvi, si una valvula tancada esta entre arcs amb el mateix sector, el manté; si esta entre 1 i 1, manté 1, vol dir que no fa frontera; si esta entre -1 i -1, no canvia, manté Conflict + + update amsa_pgr_node n set mapzone_id ='0' + from + (select node_id,count (distinct mapzone_id) from amsa_pgr_node + group by node_id + having count(distinct mapzone_id )>1) s + where n.node_id =s.node_id; + + -- els connecs agafen el mapzone_id de l'arc al que estan associats + end if; + + v_return_text = concat('OK: ', upper(v_mapzone_name)); + +end if; + +return v_return_text; +end; +$function$ +; \ No newline at end of file diff --git a/dev/v3/analysis/graf/ws_gw_fct_grafanalytics_mapzones_config.sql b/dev/v3/graf/ws_gw_fct_grafanalytics_mapzones_config.sql similarity index 100% rename from dev/v3/analysis/graf/ws_gw_fct_grafanalytics_mapzones_config.sql rename to dev/v3/graf/ws_gw_fct_grafanalytics_mapzones_config.sql diff --git a/dev/v3/analysis/graf/ws_gw_fct_grafanalytics_toarc.sql b/dev/v3/graf/ws_gw_fct_grafanalytics_toarc.sql similarity index 100% rename from dev/v3/analysis/graf/ws_gw_fct_grafanalytics_toarc.sql rename to dev/v3/graf/ws_gw_fct_grafanalytics_toarc.sql diff --git a/dev/v3/graf/ws_pgrouting_minsector_v3.sql b/dev/v3/graf/ws_pgrouting_minsector_v3.sql new file mode 100644 index 0000000000..d2a2024c7d --- /dev/null +++ b/dev/v3/graf/ws_pgrouting_minsector_v3.sql @@ -0,0 +1,166 @@ +/* +This file is part of Giswater 3 +The program is free software: you can redistribute it and/or modify it under the terms of the GNU General Public License as published by the Free Software Foundation, either version 3 of the License, or (at your option) any later version. +This version of Giswater is provided by Giswater Association + +This code of mapzones have been provide by Claudia Dragoste +*/ + + +CREATE OR REPLACE FUNCTION amsa_fct_pgr_minsector() + RETURNS text + LANGUAGE plpgsql +AS $function$ + +/* example +SELECT amsa_fct_pgr_minsector(); + +Consulta per visualitzar els arcs amb les seves geometries: + +select a.arc_id, p.mapzone_id, p.macro_minsector_id, p.minsector_id, a.the_geom +from amsa_pgr_arc p +join +(select arc_id, the_geom from arc) a on p.pgr_arc_id =a.arc_id::int; + +Consulta per visualitzar els nodes amb les seves geometries : + +select n.node_id, p.mapzone_id, p.macro_minsector_id, p.minsector_id, n.the_geom from amsa_pgr_node p +join +(select node_id, the_geom from node) n on p.pgr_node_id =n.node_id::int; + +*/ + +declare + +v_query text; +v_record record; +v_record_id integer=0; +v_arc_id integer=0; +v_id integer=0; +v_i integer; +v_return_text text; +v_field_name text; +v_affectrow int; + + + +begin + +--SET search_path = "ws_github_full", public; + +-- no es guarda la geometria, s'ha de fer un join amb la taula node per recuperar-la per els resultats + +truncate amsa_pgr_node; +truncate amsa_pgr_arc; + +insert into amsa_pgr_node (pgr_node_id, node_id) +(SELECT node_id::int, node_id + FROM node n + join value_state_type s on s.id =n.state_type + where n.state=1 and s.is_operative =true +); + +insert into amsa_pgr_arc (pgr_arc_id,arc_id, pgr_node_1,pgr_node_2, node_1, node_2) +(SELECT a.arc_id::int, a.arc_id, a.node_1::int, a.node_2::int,a.node_1, a.node_2 + FROM arc a + join value_state_type s on s.id =a.state_type + where a.state=1 and s.is_operative =true + and a.node_1 is not null and a.node_2 is not null -- evita el crash de pgr_connectedComponents +); + +-- GENERAR ELS MACRO_MINSECTORS + +update amsa_pgr_arc a set modif=true, graph_delimiter='macro_minsector', cost=-1, reverse_cost=-1 +from +(select node_id , unnest(string_to_array(json_array_elements_text((parameters::json->>'inletArc')::json),',')) as InletArc +from config_graph_inlet +) s +where a.arc_id=s.InletArc; + +truncate amsa_pgr_connectedcomponents; +insert into amsa_pgr_connectedComponents +(SELECT * FROM pgr_connectedComponents( + 'SELECT pgr_arc_id as id, pgr_node_1 as source, pgr_node_2 as target, cost +FROM amsa_pgr_arc a' +) +); + +-- actualitzar el camp macro_minsector_id per els arcs i els nodes + +UPDATE amsa_pgr_node n SET macro_minsector_id=c.component +FROM amsa_pgr_connectedcomponents c +where n.pgr_node_id =c.node; + +UPDATE amsa_pgr_arc a SET macro_minsector_id=c.component +FROM amsa_pgr_connectedcomponents c +where a.pgr_node_1 =c.node; + +-- GENERAR ELS MINSECTORS + +update amsa_pgr_node n set modif=true, graph_delimiter='minsector' +from +(select node_id + from node n + join cat_node c on n.nodecat_id=c.id + join cat_feature_node cf on c.nodetype_id =cf.id + where cf.graph_delimiter ='MINSECTOR' +) s +where n.node_id=s.node_id; + + +--comença el proces de desconnectar les fronteres MINSECTOR; es crea un arc nou amb cost i reverse cost -1 + +EXECUTE 'select max (pgr_node_id) from amsa_pgr_node' +INTO v_record_id; +EXECUTE 'select max (pgr_arc_id) from amsa_pgr_arc' +INTO v_arc_id; +if v_record_id>v_arc_id then v_id=v_record_id; +else v_id=v_arc_id; +end if; + +FOR v_record IN + SELECT distinct on (n.pgr_node_id) n.pgr_node_id, n.graph_delimiter, a.pgr_arc_id,a.pgr_node_1,a.pgr_node_2 + FROM amsa_pgr_node n + join amsa_pgr_arc a on n.pgr_node_id in (a.pgr_node_1, a.pgr_node_2) + where n.graph_delimiter='minsector' +LOOP + v_id=v_id+1; + insert into amsa_pgr_node(pgr_node_id, node_id,modif,graph_delimiter) values (v_id, v_record.pgr_node_id::text,true,v_record.graph_delimiter); + if v_record.pgr_node_id=v_record.pgr_node_1 then + update amsa_pgr_arc set pgr_node_1=v_id + where pgr_arc_id=v_record.pgr_arc_id; + else + update amsa_pgr_arc set pgr_node_2=v_id + where pgr_arc_id=v_record.pgr_arc_id; + end if; + v_id=v_id+1; + insert into amsa_pgr_arc(pgr_arc_id, arc_id, pgr_node_1,pgr_node_2,node_1,node_2, modif,graph_delimiter, cost, reverse_cost) values (v_id, v_record.pgr_arc_id::text,v_record.pgr_node_id, v_id-1,v_record.pgr_node_id,v_record.pgr_node_id, true,v_record.graph_delimiter, -1, -1); +END LOOP; + +truncate amsa_pgr_connectedcomponents; +insert into amsa_pgr_connectedComponents +(SELECT * FROM pgr_connectedComponents( + 'SELECT pgr_arc_id as id, pgr_node_1 as source, pgr_node_2 as target, cost +FROM amsa_pgr_arc a' +) +); + + +-- actualitzar el camp component per els arcs i els nodes + +UPDATE amsa_pgr_node n SET minsector_id=c.component +FROM amsa_pgr_connectedcomponents c +where n.pgr_node_id =c.node; + +UPDATE amsa_pgr_arc a SET minsector_id=c.component +FROM amsa_pgr_connectedcomponents c +where a.pgr_node_1 =c.node; + +-- els connecs agafen el mapzone_id de l'arc al que estan associats + +v_return_text = 'OK: MINSECTOR'; + +return v_return_text; +end; +$function$ +; \ No newline at end of file diff --git a/dev/v4/ws/ddlview.sql b/dev/v4/ws/ddlview.sql deleted file mode 100644 index 7b7e44ea03..0000000000 --- a/dev/v4/ws/ddlview.sql +++ /dev/null @@ -1,129 +0,0 @@ -/* -This file is part of Giswater 3 -The program is free software: you can redistribute it and/or modify it under the terms of the GNU General Public License as published by the Free Software Foundation, either version 3 of the License, or (at your option) any later version. -This version of Giswater is provided by Giswater Association -*/ - -SET search_path = SCHEMA_NAME, public, pg_catalog; - -ALTER TABLE arc rename depth to _depth; -ALTER TABLE arc rename staticpressure to _staticpressure; - - -CREATE OR REPLACE VIEW vu_arc AS - SELECT arc.arc_id, - arc.code, - arc.node_1, - arc.node_2, - arc.elevation1, - arc.depth1, - arc.elevation2, - arc.depth2, - arc.arccat_id, - cat_arc.arctype_id AS arc_type, - cat_feature.system_id AS sys_type, - cat_arc.matcat_id AS cat_matcat_id, - cat_arc.pnom AS cat_pnom, - cat_arc.dnom AS cat_dnom, - arc.epa_type, - arc.expl_id, - exploitation.macroexpl_id, - arc.sector_id, - sector.name AS sector_name, - sector.macrosector_id, - arc.state, - arc.state_type, - arc.annotation, - arc.observ, - arc.comment, - st_length2d(arc.the_geom)::numeric(12,2) AS gis_length, - arc.custom_length, - arc.minsector_id, - arc.dma_id, - dma.name AS dma_name, - dma.macrodma_id, - arc.presszone_id, - presszone.name AS presszone_name, - arc.dqa_id, - dqa.name AS dqa_name, - dqa.macrodqa_id, - arc.soilcat_id, - arc.function_type, - arc.category_type, - arc.fluid_type, - arc.location_type, - arc.workcat_id, - arc.workcat_id_end, - arc.buildercat_id, - arc.builtdate, - arc.enddate, - arc.ownercat_id, - arc.muni_id, - arc.postcode, - arc.district_id, - c.descript::character varying(100) AS streetname, - arc.postnumber, - arc.postcomplement, - d.descript::character varying(100) AS streetname2, - arc.postnumber2, - arc.postcomplement2, - arc.descript, - concat(cat_feature.link_path, arc.link) AS link, - arc.verified, - arc.undelete, - cat_arc.label, - arc.label_x, - arc.label_y, - arc.label_rotation, - arc.publish, - arc.inventory, - arc.num_value, - cat_arc.arctype_id AS cat_arctype_id, - arc.nodetype_1, - arc.staticpress1, - arc.nodetype_2, - arc.staticpress2, - date_trunc('second'::text, arc.tstamp) AS tstamp, - arc.insert_user, - date_trunc('second'::text, arc.lastupdate) AS lastupdate, - arc.lastupdate_user, - arc.the_geom, - CASE WHEN depth1 IS NOT NULL AND depth2 IS NOT NULL THEN ((depth1 + depth2)/2)::numeric(12,3) ELSE NULL::numeric(12,3) END as depth, - arc.adate, - arc.adescript, - dma.stylesheet ->> 'featureColor'::text AS dma_style, - presszone.stylesheet ->> 'featureColor'::text AS presszone_style, - arc.workcat_id_plan, - arc.asset_id, - arc.pavcat_id, - arc.om_state, - arc.conserv_state, - e.flow_max, - e.flow_min, - e.flow_avg, - e.vel_max, - e.vel_min, - e.vel_avg, - arc.parent_id, - arc.expl_id2, - vst.is_operative, - mu.region_id, - mu.province_id - FROM arc - LEFT JOIN sector ON arc.sector_id = sector.sector_id - LEFT JOIN exploitation ON arc.expl_id = exploitation.expl_id - LEFT JOIN cat_arc ON arc.arccat_id::text = cat_arc.id::text - JOIN cat_feature ON cat_feature.id::text = cat_arc.arctype_id::text - LEFT JOIN dma ON arc.dma_id = dma.dma_id - LEFT JOIN dqa ON arc.dqa_id = dqa.dqa_id - LEFT JOIN presszone ON presszone.presszone_id::text = arc.presszone_id::text - LEFT JOIN v_ext_streetaxis c ON c.id::text = arc.streetaxis_id::text - LEFT JOIN v_ext_streetaxis d ON d.id::text = arc.streetaxis2_id::text - LEFT JOIN arc_add e ON arc.arc_id::text = e.arc_id::text - LEFT JOIN value_state_type vst ON vst.id = arc.state_type - LEFT JOIN ext_municipality mu ON arc.muni_id = mu.muni_id; - -ALTER TABLE vu_arc - OWNER TO role_admin; -GRANT ALL ON TABLE vu_arc TO role_admin; -GRANT ALL ON TABLE vu_arc TO role_basic; \ No newline at end of file diff --git a/updates/36/36012/changelog.txt b/updates/36/36012/changelog.txt index e5a5eccb14..752949e11d 100644 --- a/updates/36/36012/changelog.txt +++ b/updates/36/36012/changelog.txt @@ -3,7 +3,7 @@ - New function gw_fct_setpsectorcostremovedpipes (associated fid 523) - Separate `archived_*` tables into 3 tables (archived_rpt_inp_*, archived_rpt_*, archived_rpt_*_stats) - Remove duplicated vertex generated because of the fusion. Use st_removerepeatedpoints function for the new geom -- New view v_ext_municipality filtered by selected exploitations. Use it on search tool +- New view v_ext_municipality filtered by selected. Use it on search tool - New behaviour for inlets as a junctions when they are on the end of a sector without continuity with the next one - Add new fields on inventory tables for UD node, arc, connec, gully: placement_type , - Change all columns `code` from varchar(30) to text