From 6371e06b18de7e8c201e913c97c72e799a232483 Mon Sep 17 00:00:00 2001 From: Daniel Marin Date: Thu, 22 Aug 2024 16:19:23 +0200 Subject: [PATCH] fix(ftrg): check first if addfield table exists before do action, and remove trailing whitespaces --- ud/ftrg/ud_gw_trg_edit_arc.sql | 38 ++- ud/ftrg/ud_gw_trg_edit_connec.sql | 40 +-- ud/ftrg/ud_gw_trg_edit_gully.sql | 38 ++- ud/ftrg/ud_gw_trg_edit_node.sql | 39 +-- ws/ftrg/ws_gw_trg_edit_arc.sql | 263 ++++++++++---------- ws/ftrg/ws_gw_trg_edit_connec.sql | 388 +++++++++++++++--------------- ws/ftrg/ws_gw_trg_edit_node.sql | 39 ++- 7 files changed, 462 insertions(+), 383 deletions(-) diff --git a/ud/ftrg/ud_gw_trg_edit_arc.sql b/ud/ftrg/ud_gw_trg_edit_arc.sql index e57fc5d43c..2000ad6b8d 100644 --- a/ud/ftrg/ud_gw_trg_edit_arc.sql +++ b/ud/ftrg/ud_gw_trg_edit_arc.sql @@ -38,6 +38,7 @@ v_seq_name text; v_seq_code text; v_code_prefix text; v_arc_id text; +v_childtable_name text; BEGIN EXECUTE 'SET search_path TO '||quote_literal(TG_TABLE_SCHEMA)||', public'; @@ -516,9 +517,12 @@ BEGIN USING NEW INTO v_new_value_param; - IF v_new_value_param IS NOT NULL THEN - EXECUTE 'INSERT INTO man_arc_'||lower(v_customfeature)||' (arc_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||')' - USING NEW.arc_id, v_new_value_param; + v_childtable_name := 'man_arc_' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + IF v_new_value_param IS NOT NULL THEN + EXECUTE 'INSERT INTO '||v_childtable_name||' (arc_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||')' + USING NEW.arc_id, v_new_value_param; + END IF; END IF; END LOOP; END IF; @@ -730,15 +734,20 @@ BEGIN USING OLD INTO v_old_value_param; - IF (v_new_value_param IS NOT NULL AND v_old_value_param!=v_new_value_param) OR (v_new_value_param IS NOT NULL AND v_old_value_param IS NULL) THEN - EXECUTE 'INSERT INTO man_arc_'||lower(v_customfeature)||' (arc_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||') - ON CONFLICT (arc_id) - DO UPDATE SET '||v_addfields.param_name||'=$2::'||v_addfields.datatype_id||' WHERE man_arc_'||lower(v_customfeature)||'.arc_id=$1' - USING NEW.arc_id, v_new_value_param; - ELSIF v_new_value_param IS NULL AND v_old_value_param IS NOT NULL THEN - EXECUTE 'UPDATE man_arc_'||lower(v_customfeature)||' SET '||v_addfields.param_name||' = null WHERE man_arc_'||lower(v_customfeature)||'.arc_id=$1' - USING NEW.arc_id; + + v_childtable_name := 'man_arc_' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + IF (v_new_value_param IS NOT NULL AND v_old_value_param!=v_new_value_param) OR (v_new_value_param IS NOT NULL AND v_old_value_param IS NULL) THEN + EXECUTE 'INSERT INTO '||v_childtable_name||' (arc_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||') + ON CONFLICT (arc_id) + DO UPDATE SET '||v_addfields.param_name||'=$2::'||v_addfields.datatype_id||' WHERE '||v_childtable_name||'.arc_id=$1' + USING NEW.arc_id, v_new_value_param; + + ELSIF v_new_value_param IS NULL AND v_old_value_param IS NOT NULL THEN + EXECUTE 'UPDATE '||v_childtable_name||' SET '||v_addfields.param_name||' = null WHERE '||v_childtable_name||'.arc_id=$1' + USING NEW.arc_id; + END IF; END IF; END LOOP; END IF; @@ -770,8 +779,11 @@ BEGIN -- Delete childtable addfields (after or before deletion of arc, doesn't matter) v_customfeature = old.arc_type; v_arc_id = old.arc_id; - - EXECUTE 'DELETE FROM man_arc_'||lower(v_customfeature)||' WHERE arc_id = '||quote_literal(v_arc_id)||''; + + v_childtable_name := 'man_arc_' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + EXECUTE 'DELETE FROM '||v_childtable_name||' WHERE arc_id = '||quote_literal(v_arc_id)||''; + END IF; RETURN NULL; diff --git a/ud/ftrg/ud_gw_trg_edit_connec.sql b/ud/ftrg/ud_gw_trg_edit_connec.sql index 4d754f18d3..baf528aa1e 100644 --- a/ud/ftrg/ud_gw_trg_edit_connec.sql +++ b/ud/ftrg/ud_gw_trg_edit_connec.sql @@ -41,6 +41,7 @@ v_seq_name text; v_seq_code text; v_code_prefix text; v_connec_id text; +v_childtable_name text; BEGIN @@ -546,10 +547,14 @@ BEGIN USING NEW INTO v_new_value_param; - IF v_new_value_param IS NOT NULL THEN - EXECUTE 'INSERT INTO man_connec_'||lower(v_customfeature)||' (connec_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||')' - USING NEW.connec_id, v_new_value_param; + v_childtable_name := 'man_connec' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + IF v_new_value_param IS NOT NULL THEN + EXECUTE 'INSERT INTO '||v_childtable_name||' (connec_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||')' + USING NEW.connec_id, v_new_value_param; + END IF; END IF; + END LOOP; END IF; @@ -778,15 +783,18 @@ BEGIN USING OLD INTO v_old_value_param; - IF (v_new_value_param IS NOT NULL AND v_old_value_param!=v_new_value_param) OR (v_new_value_param IS NOT NULL AND v_old_value_param IS NULL) THEN - EXECUTE 'INSERT INTO man_connec_'||lower(v_customfeature)||' (connec_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||') - ON CONFLICT (connec_id) - DO UPDATE SET '||v_addfields.param_name||'=$2::'||v_addfields.datatype_id||' WHERE man_connec_'||lower(v_customfeature)||'.connec_id=$1' - USING NEW.connec_id, v_new_value_param; - - ELSIF v_new_value_param IS NULL AND v_old_value_param IS NOT NULL THEN - EXECUTE 'UPDATE man_connec_'||lower(v_customfeature)||' SET '||v_addfields.param_name||' = null WHERE man_connec_'||lower(v_customfeature)||'.connec_id=$1' - USING NEW.connec_id; + v_childtable_name := 'man_connec' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + IF (v_new_value_param IS NOT NULL AND v_old_value_param!=v_new_value_param) OR (v_new_value_param IS NOT NULL AND v_old_value_param IS NULL) THEN + EXECUTE 'INSERT INTO '||v_childtable_name||' (connec_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||') + ON CONFLICT (connec_id) + DO UPDATE SET '||v_addfields.param_name||'=$2::'||v_addfields.datatype_id||' WHERE '||v_childtable_name||'.connec_id=$1' + USING NEW.connec_id, v_new_value_param; + + ELSIF v_new_value_param IS NULL AND v_old_value_param IS NOT NULL THEN + EXECUTE 'UPDATE '||v_childtable_name||' SET '||v_addfields.param_name||' = null WHERE '||v_childtable_name||'.connec_id=$1' + USING NEW.connec_id; + END IF; END IF; END LOOP; END IF; @@ -814,8 +822,12 @@ BEGIN -- Delete childtable addfields (after or before deletion of connec, doesn't matter) v_customfeature = old.connec_type; v_connec_id = old.connec_id; - - EXECUTE 'DELETE FROM man_connec_'||lower(v_customfeature)||' WHERE connec_id = '||quote_literal(v_connec_id)||''; + + + v_childtable_name := 'man_connec' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + EXECUTE 'DELETE FROM '||v_childtable_name||' WHERE connec_id = '||quote_literal(v_connec_id)||''; + END IF; -- delete links FOR v_record_link IN SELECT * FROM link WHERE feature_type='CONNEC' AND feature_id=OLD.connec_id diff --git a/ud/ftrg/ud_gw_trg_edit_gully.sql b/ud/ftrg/ud_gw_trg_edit_gully.sql index 0af28999b3..464b3e328a 100644 --- a/ud/ftrg/ud_gw_trg_edit_gully.sql +++ b/ud/ftrg/ud_gw_trg_edit_gully.sql @@ -69,6 +69,7 @@ v_seq_name text; v_seq_code text; v_code_prefix text; v_gully_id text; +v_childtable_name text; BEGIN @@ -643,9 +644,12 @@ BEGIN USING NEW INTO v_new_value_param; - IF v_new_value_param IS NOT NULL THEN - EXECUTE 'INSERT INTO man_gully_'||lower(v_customfeature)||' (gully_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||')' - USING NEW.gully_id, v_new_value_param; + v_childtable_name := 'man_gully_' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + IF v_new_value_param IS NOT NULL THEN + EXECUTE 'INSERT INTO '||v_childtable_name||' (gully_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||')' + USING NEW.gully_id, v_new_value_param; + END IF; END IF; END LOOP; END IF; @@ -942,15 +946,20 @@ BEGIN USING OLD INTO v_old_value_param; - IF (v_new_value_param IS NOT NULL AND v_old_value_param!=v_new_value_param) OR (v_new_value_param IS NOT NULL AND v_old_value_param IS NULL) THEN - EXECUTE 'INSERT INTO man_gully_'||lower(v_customfeature)||' (gully_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||') - ON CONFLICT (gully_id) - DO UPDATE SET '||v_addfields.param_name||'=$2::'||v_addfields.datatype_id||' WHERE man_gully_'||lower(v_customfeature)||'.gully_id=$1' - USING NEW.gully_id, v_new_value_param; - ELSIF v_new_value_param IS NULL AND v_old_value_param IS NOT NULL THEN - EXECUTE 'UPDATE man_gully_'||lower(v_customfeature)||' SET '||v_addfields.param_name||' = null WHERE man_gully_'||lower(v_customfeature)||'.gully_id=$1' - USING NEW.gully_id; + + v_childtable_name := 'man_gully_' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + IF (v_new_value_param IS NOT NULL AND v_old_value_param!=v_new_value_param) OR (v_new_value_param IS NOT NULL AND v_old_value_param IS NULL) THEN + EXECUTE 'INSERT INTO '||v_childtable_name||' (gully_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||') + ON CONFLICT (gully_id) + DO UPDATE SET '||v_addfields.param_name||'=$2::'||v_addfields.datatype_id||' WHERE '||v_childtable_name||'.gully_id=$1' + USING NEW.gully_id, v_new_value_param; + + ELSIF v_new_value_param IS NULL AND v_old_value_param IS NOT NULL THEN + EXECUTE 'UPDATE '||v_childtable_name||' SET '||v_addfields.param_name||' = null WHERE '||v_childtable_name||'.gully_id=$1' + USING NEW.gully_id; + END IF; END IF; END LOOP; END IF; @@ -978,8 +987,11 @@ BEGIN -- Delete childtable addfields (after or before deletion of gully, doesn't matter) v_customfeature = old.gully_type; v_gully_id = old.gully_id; - - EXECUTE 'DELETE FROM man_gully_'||lower(v_customfeature)||' WHERE gully_id = '||quote_literal(v_gully_id)||''; + + v_childtable_name := 'man_gully_' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + EXECUTE 'DELETE FROM '||v_childtable_name||' WHERE gully_id = '||quote_literal(v_gully_id)||''; + END IF; -- delete links FOR v_record_link IN SELECT * FROM link WHERE feature_type='GULLY' AND feature_id=OLD.gully_id diff --git a/ud/ftrg/ud_gw_trg_edit_node.sql b/ud/ftrg/ud_gw_trg_edit_node.sql index 45337d75cb..805ff2b5e7 100644 --- a/ud/ftrg/ud_gw_trg_edit_node.sql +++ b/ud/ftrg/ud_gw_trg_edit_node.sql @@ -77,6 +77,8 @@ v_input json; v_auto_sander boolean; v_node_id text; +v_childtable_name text; + BEGIN EXECUTE 'SET search_path TO '||quote_literal(TG_TABLE_SCHEMA)||', public'; @@ -693,9 +695,12 @@ BEGIN USING NEW INTO v_new_value_param; - IF v_new_value_param IS NOT NULL THEN - EXECUTE 'INSERT INTO man_node_'||lower(v_customfeature)||' (node_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||')' - USING NEW.node_id, v_new_value_param; + v_childtable_name := 'man_node' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + IF v_new_value_param IS NOT NULL THEN + EXECUTE 'INSERT INTO '||v_childtable_name||' (node_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||')' + USING NEW.node_id, v_new_value_param; + END IF; END IF; END LOOP; END IF; @@ -966,15 +971,18 @@ BEGIN USING OLD INTO v_old_value_param; - IF (v_new_value_param IS NOT NULL AND v_old_value_param!=v_new_value_param) OR (v_new_value_param IS NOT NULL AND v_old_value_param IS NULL) THEN - EXECUTE 'INSERT INTO man_node_'||lower(v_customfeature)||' (node_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||') - ON CONFLICT (node_id) - DO UPDATE SET '||v_addfields.param_name||'=$2::'||v_addfields.datatype_id||' WHERE man_node_'||lower(v_customfeature)||'.node_id=$1' - USING NEW.node_id, v_new_value_param; - - ELSIF v_new_value_param IS NULL AND v_old_value_param IS NOT NULL THEN - EXECUTE 'UPDATE man_node_'||lower(v_customfeature)||' SET '||v_addfields.param_name||' = null WHERE man_node_'||lower(v_customfeature)||'.node_id=$1' - USING NEW.node_id; + v_childtable_name := 'man_node' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + IF (v_new_value_param IS NOT NULL AND v_old_value_param!=v_new_value_param) OR (v_new_value_param IS NOT NULL AND v_old_value_param IS NULL) THEN + EXECUTE 'INSERT INTO '||v_childtable_name||' (node_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||') + ON CONFLICT (node_id) + DO UPDATE SET '||v_addfields.param_name||'=$2::'||v_addfields.datatype_id||' WHERE '||v_childtable_name||'.node_id=$1' + USING NEW.node_id, v_new_value_param; + + ELSIF v_new_value_param IS NULL AND v_old_value_param IS NOT NULL THEN + EXECUTE 'UPDATE '||v_childtable_name||' SET '||v_addfields.param_name||' = null WHERE '||v_childtable_name||'.node_id=$1' + USING NEW.node_id; + END IF; END IF; END LOOP; END IF; @@ -1005,8 +1013,11 @@ BEGIN -- Delete childtable addfields (after or before deletion of node, doesn't matter) v_customfeature = old.node_type; v_node_id = old.node_id; - - EXECUTE 'DELETE FROM man_node_'||lower(v_customfeature)||' WHERE node_id = '||quote_literal(v_node_id)||''; + + v_childtable_name := 'man_node' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + EXECUTE 'DELETE FROM '||v_childtable_name||' WHERE node_id = '||quote_literal(v_node_id)||''; + END IF; RETURN NULL; END IF; diff --git a/ws/ftrg/ws_gw_trg_edit_arc.sql b/ws/ftrg/ws_gw_trg_edit_arc.sql index a7f8ff59c3..97b32a49fe 100644 --- a/ws/ftrg/ws_gw_trg_edit_arc.sql +++ b/ws/ftrg/ws_gw_trg_edit_arc.sql @@ -9,7 +9,7 @@ This version of Giswater is provided by Giswater Association CREATE OR REPLACE FUNCTION "SCHEMA_NAME".gw_trg_edit_arc() RETURNS trigger AS $BODY$ -DECLARE +DECLARE v_inp_table varchar; v_man_table varchar; v_sql varchar; @@ -34,13 +34,14 @@ v_seq_name text; v_seq_code text; v_code_prefix text; v_arc_id text; +v_childtable_name text; BEGIN EXECUTE 'SET search_path TO '||quote_literal(TG_TABLE_SCHEMA)||', public'; v_man_table:= TG_ARGV[0]; - --modify values for custom view inserts + --modify values for custom view inserts IF v_man_table IN (SELECT id FROM cat_feature) THEN v_customfeature:=v_man_table; v_man_table:=(SELECT man_table FROM cat_feature_arc c JOIN sys_feature_cat s ON c.type = s.id WHERE c.id=v_man_table); @@ -57,20 +58,20 @@ BEGIN EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, "data":{"message":"3246", "function":"1302","debug_msg":null}}$$);'; END IF; - + -- transforming streetaxis name into id v_streetaxis = (SELECT id FROM v_ext_streetaxis WHERE (muni_id = NEW.muni_id OR muni_id IS NULL) AND descript = NEW.streetname LIMIT 1); v_streetaxis2 = (SELECT id FROM v_ext_streetaxis WHERE (muni_id = NEW.muni_id OR muni_id IS NULL) AND descript = NEW.streetname2 LIMIT 1); END IF; - + IF TG_OP = 'INSERT' THEN -- setting psector vdefault as visible IF NEW.state = 2 THEN INSERT INTO selector_psector (psector_id, cur_user) VALUES (v_psector, current_user) ON CONFLICT DO NOTHING; END IF; - + -- Arc ID IF NEW.arc_id != (SELECT last_value::text FROM urn_id_seq) OR NEW.arc_id IS NULL THEN NEW.arc_id = (SELECT nextval('urn_id_seq')); @@ -81,7 +82,7 @@ BEGIN IF ((SELECT COUNT(*) FROM cat_arc WHERE active IS TRUE) = 0) THEN EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, "data":{"message":"1020", "function":"1302","debug_msg":null}}$$);'; - END IF; + END IF; -- get vdefault values using config user values IF v_customfeature IS NOT NULL THEN @@ -100,125 +101,125 @@ BEGIN "data":{"message":"1088", "function":"1302","debug_msg":null}}$$);'; END IF; END IF; - - + + -- Set EPA type IF (NEW.epa_type IS NULL) THEN - NEW.epa_type = 'PIPE'; + NEW.epa_type = 'PIPE'; END IF; - - + + -- Exploitation IF (NEW.expl_id IS NULL) THEN - + -- control error without any mapzones defined on the table of mapzone IF ((SELECT COUNT(*) FROM exploitation WHERE active IS TRUE) = 0) THEN EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, "data":{"message":"1110", "function":"1302","debug_msg":null}}$$);'; END IF; - + -- getting value default IF (NEW.expl_id IS NULL) THEN NEW.expl_id := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_exploitation_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + -- getting value from geometry of mapzone IF (NEW.expl_id IS NULL) THEN SELECT count(*) INTO v_count FROM exploitation WHERE ST_DWithin(NEW.the_geom, exploitation.the_geom,0.001) AND active IS TRUE; IF v_count = 1 THEN NEW.expl_id = (SELECT expl_id FROM exploitation WHERE ST_DWithin(NEW.the_geom, exploitation.the_geom,0.001) AND active IS TRUE LIMIT 1); ELSE - NEW.expl_id =(SELECT expl_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) + NEW.expl_id =(SELECT expl_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) order by ST_Distance (NEW.the_geom, v_edit_arc.the_geom) LIMIT 1); - END IF; + END IF; END IF; - + -- control error when no value IF (NEW.expl_id IS NULL) THEN EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, "data":{"message":"2012", "function":"1302","debug_msg":"'||NEW.arc_id::text||'"}}$$);'; - END IF; + END IF; END IF; - - + + -- Sector ID IF (NEW.sector_id IS NULL) THEN - + -- control error without any mapzones defined on the table of mapzone IF ((SELECT COUNT(*) FROM sector WHERE active IS TRUE ) = 0) THEN EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, "data":{"message":"1008", "function":"1302","debug_msg":null}}$$);'; END IF; - + -- getting value default IF (NEW.sector_id IS NULL) THEN NEW.sector_id := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_sector_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + -- getting value from geometry of mapzone IF (NEW.sector_id IS NULL) THEN SELECT count(*) INTO v_count FROM sector WHERE ST_DWithin(NEW.the_geom, sector.the_geom,0.001) AND active IS TRUE; IF v_count = 1 THEN NEW.sector_id = (SELECT sector_id FROM sector WHERE ST_DWithin(NEW.the_geom, sector.the_geom,0.001) AND active IS TRUE LIMIT 1); ELSE - NEW.sector_id =(SELECT sector_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) + NEW.sector_id =(SELECT sector_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) order by ST_Distance (NEW.the_geom, v_edit_arc.the_geom) LIMIT 1); - END IF; + END IF; END IF; - + -- control error when no value IF (NEW.sector_id IS NULL) THEN NEW.sector_id =0; - END IF; + END IF; END IF; - - + + -- Dma ID IF (NEW.dma_id IS NULL) THEN - + -- control error without any mapzones defined on the table of mapzone IF ((SELECT COUNT(*) FROM dma WHERE active IS TRUE ) = 0) THEN EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, "data":{"message":"1012", "function":"1302","debug_msg":null}}$$);'; END IF; - + -- getting value default IF (NEW.dma_id IS NULL) THEN NEW.dma_id := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_dma_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + -- getting value from geometry of mapzone IF (NEW.dma_id IS NULL) THEN SELECT count(*) INTO v_count FROM dma WHERE ST_DWithin(NEW.the_geom, dma.the_geom,0.001) AND active IS TRUE ; IF v_count = 1 THEN NEW.dma_id = (SELECT dma_id FROM dma WHERE ST_DWithin(NEW.the_geom, dma.the_geom,0.001) AND active IS TRUE LIMIT 1); ELSE - NEW.dma_id =(SELECT dma_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) + NEW.dma_id =(SELECT dma_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) order by ST_Distance (NEW.the_geom, v_edit_arc.the_geom) LIMIT 1); - END IF; + END IF; END IF; - + -- control error when no value IF (NEW.dma_id IS NULL) THEN NEW.dma_id =0; - END IF; + END IF; END IF; - - + + -- Presszone IF (NEW.presszone_id IS NULL) THEN - + -- control error without any mapzones defined on the table of mapzone IF ((SELECT COUNT(*) FROM presszone WHERE active IS TRUE ) = 0) THEN EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, "data":{"message":"3106", "function":"1302","debug_msg":null}}$$);'; END IF; - + -- getting value default IF (NEW.presszone_id IS NULL) THEN NEW.presszone_id := (SELECT "value" FROM config_param_user WHERE "parameter"='presszone_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + -- getting value from geometry of mapzone IF (NEW.presszone_id IS NULL) THEN SELECT count(*) INTO v_count FROM presszone WHERE ST_DWithin(NEW.the_geom, presszone.the_geom,0.001) AND active IS TRUE ; @@ -227,52 +228,52 @@ BEGIN ELSE NEW.presszone_id =(SELECT presszone_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) order by ST_Distance (NEW.the_geom, v_edit_arc.the_geom) LIMIT 1); - END IF; + END IF; END IF; - + -- control error when no value IF (NEW.presszone_id IS NULL) THEN NEW.presszone_id =0; - END IF; + END IF; END IF; - - -- Municipality + + -- Municipality IF (NEW.muni_id IS NULL) THEN - + -- getting value default IF (NEW.muni_id IS NULL) THEN NEW.muni_id := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_municipality_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + -- getting value from geometry of mapzone IF (NEW.muni_id IS NULL) THEN SELECT count(*) INTO v_count FROM ext_municipality WHERE ST_DWithin(NEW.the_geom, ext_municipality.the_geom,0.001) AND active IS TRUE ; IF v_count = 1 THEN - NEW.muni_id = (SELECT muni_id FROM ext_municipality WHERE ST_DWithin(NEW.the_geom, ext_municipality.the_geom,0.001) + NEW.muni_id = (SELECT muni_id FROM ext_municipality WHERE ST_DWithin(NEW.the_geom, ext_municipality.the_geom,0.001) AND active IS TRUE LIMIT 1); ELSE - NEW.muni_id =(SELECT muni_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) + NEW.muni_id =(SELECT muni_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) order by ST_Distance (NEW.the_geom, v_edit_arc.the_geom) LIMIT 1); - END IF; - END IF; + END IF; + END IF; END IF; - - -- District + + -- District IF (NEW.district_id IS NULL) THEN - + -- getting value from geometry of mapzone IF (NEW.district_id IS NULL) THEN SELECT count(*) INTO v_count FROM ext_district WHERE ST_DWithin(NEW.the_geom, ext_district.the_geom,0.001); IF v_count = 1 THEN NEW.district_id = (SELECT district_id FROM ext_district WHERE ST_DWithin(NEW.the_geom, ext_district.the_geom,0.001) LIMIT 1); ELSIF v_count > 1 THEN - NEW.district_id =(SELECT district_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) + NEW.district_id =(SELECT district_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) order by ST_Distance (NEW.the_geom, v_edit_arc.the_geom) LIMIT 1); - END IF; - END IF; + END IF; + END IF; END IF; - - + + -- State IF (NEW.state IS NULL) THEN NEW.state := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_state_vdefault' AND "cur_user"="current_user"() LIMIT 1); @@ -308,27 +309,27 @@ BEGIN IF NEW.inventory IS NULL THEN NEW.inventory := (SELECT "value" FROM config_param_system WHERE "parameter"='edit_inventory_sysvdefault'); END IF; - + --Publish IF NEW.publish IS NULL THEN NEW.publish := (SELECT "value" FROM config_param_system WHERE "parameter"='edit_publish_sysvdefault'); - END IF; + END IF; -- Code - SELECT code_autofill, cat_feature.id, addparam::json->>'code_prefix' INTO v_code_autofill_bool, v_featurecat, v_code_prefix FROM cat_feature + SELECT code_autofill, cat_feature.id, addparam::json->>'code_prefix' INTO v_code_autofill_bool, v_featurecat, v_code_prefix FROM cat_feature JOIN cat_arc ON cat_feature.id=cat_arc.arctype_id WHERE cat_arc.id=NEW.arccat_id; - + -- use specific sequence for code when its name matches featurecat_code_seq EXECUTE 'SELECT concat('||quote_literal(lower(v_featurecat))||',''_code_seq'');' INTO v_seq_name; EXECUTE 'SELECT relname FROM pg_catalog.pg_class WHERE relname='||quote_literal(v_seq_name)||';' INTO v_sql; - + IF v_sql IS NOT NULL AND NEW.code IS NULL THEN EXECUTE 'SELECT nextval('||quote_literal(v_seq_name)||');' INTO v_seq_code; NEW.code=concat(v_code_prefix,v_seq_code); END IF; - - --Copy id to code field - IF (v_code_autofill_bool IS TRUE) AND NEW.code IS NULL THEN + + --Copy id to code field + IF (v_code_autofill_bool IS TRUE) AND NEW.code IS NULL THEN NEW.code=NEW.arc_id; END IF; @@ -336,17 +337,17 @@ BEGIN IF (NEW.workcat_id IS NULL) THEN NEW.workcat_id := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_workcat_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + --Workcat_id_plan IF (NEW.workcat_id_plan IS NULL AND NEW.state = 2) THEN NEW.workcat_id_plan := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_workcat_id_plan' AND "cur_user"="current_user"() LIMIT 1); END IF; - + -- Ownercat_id IF (NEW.ownercat_id IS NULL) THEN NEW.ownercat_id := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_ownercat_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + -- Soilcat_id IF (NEW.soilcat_id IS NULL) THEN NEW.soilcat_id := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_soilcat_vdefault' AND "cur_user"="current_user"() LIMIT 1); @@ -359,17 +360,17 @@ BEGIN NEW.builtdate :=date(now()); END IF; END IF; - + -- Verified IF (NEW.verified IS NULL) THEN NEW.verified := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_verified_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + -- LINK IF (SELECT (value::json->>'fid')::boolean FROM config_param_system WHERE parameter='edit_custom_link') IS TRUE THEN NEW.link=NEW.arc_id; END IF; - + v_featurecat = (SELECT arctype_id FROM cat_arc WHERE id = NEW.arccat_id); --Location type @@ -397,7 +398,7 @@ BEGIN IF NEW.category_type IS NULL THEN NEW.category_type = (SELECT value FROM config_param_user WHERE parameter = 'edit_arc_category_vdefault' AND cur_user = current_user); - END IF; + END IF; --Function type IF NEW.function_type IS NULL AND (SELECT value FROM config_param_user WHERE parameter = 'edit_feature_function_vdefault' AND cur_user = current_user) = v_featurecat THEN @@ -407,7 +408,7 @@ BEGIN IF NEW.function_type IS NULL THEN NEW.function_type = (SELECT value FROM config_param_user WHERE parameter = 'edit_arc_function_vdefault' AND cur_user = current_user); END IF; - + --Pavement IF NEW.pavcat_id IS NULL THEN NEW.pavcat_id = (SELECT value FROM config_param_user WHERE parameter = 'edit_pavementcat_vdefault' AND cur_user = current_user); @@ -416,11 +417,11 @@ BEGIN -- FEATURE INSERT INSERT INTO arc (arc_id, code, arccat_id, epa_type, sector_id, "state", state_type, annotation, observ,"comment",custom_length,dma_id, presszone_id, soilcat_id, function_type, category_type, fluid_type, location_type, workcat_id, workcat_id_end, workcat_id_plan, buildercat_id, builtdate,enddate, ownercat_id, muni_id, postcode, district_id, streetaxis_id, postnumber, postcomplement, - streetaxis2_id,postnumber2, postcomplement2,descript,link,verified,the_geom,undelete,label_x,label_y,label_rotation, publish, inventory, expl_id, num_value, + streetaxis2_id,postnumber2, postcomplement2,descript,link,verified,the_geom,undelete,label_x,label_y,label_rotation, publish, inventory, expl_id, num_value, depth, adate, adescript, lastupdate, lastupdate_user, asset_id, pavcat_id, om_state, conserv_state, parent_id,expl_id2, brand_id, model_id, serial_number) VALUES (NEW.arc_id, NEW.code, NEW.arccat_id, NEW.epa_type, NEW.sector_id, NEW."state", NEW.state_type, NEW.annotation, NEW.observ, NEW.comment, NEW.custom_length,NEW.dma_id,NEW. presszone_id, NEW.soilcat_id, NEW.function_type, NEW.category_type, NEW.fluid_type, NEW.location_type, NEW.workcat_id, NEW.workcat_id_end, NEW.workcat_id_plan, NEW.buildercat_id, NEW.builtdate,NEW.enddate, NEW.ownercat_id, - NEW.muni_id, NEW.postcode, NEW.district_id,v_streetaxis,NEW.postnumber, NEW.postcomplement, v_streetaxis2, NEW.postnumber2, NEW.postcomplement2, NEW.descript,NEW.link, NEW.verified, + NEW.muni_id, NEW.postcode, NEW.district_id,v_streetaxis,NEW.postnumber, NEW.postcomplement, v_streetaxis2, NEW.postnumber2, NEW.postcomplement2, NEW.descript,NEW.link, NEW.verified, NEW.the_geom,NEW.undelete,NEW.label_x,NEW.label_y,NEW.label_rotation, NEW.publish, NEW.inventory, NEW.expl_id, NEW.num_value, NEW.depth, NEW.adate, NEW.adescript, NEW.lastupdate, NEW.lastupdate_user, NEW.asset_id, NEW.pavcat_id, NEW.om_state, NEW.conserv_state, NEW.parent_id, NEW.expl_id2, NEW.brand_id, NEW.model_id, NEW.serial_number); @@ -434,21 +435,21 @@ BEGIN END IF; END IF; - + -- MAN INSERT - IF v_man_table='man_pipe' THEN - INSERT INTO man_pipe (arc_id) VALUES (NEW.arc_id); - - ELSIF v_man_table='man_varc' THEN + IF v_man_table='man_pipe' THEN + INSERT INTO man_pipe (arc_id) VALUES (NEW.arc_id); + + ELSIF v_man_table='man_varc' THEN INSERT INTO man_varc (arc_id) VALUES (NEW.arc_id); ELSIF v_man_table='parent' THEN - v_man_table := (SELECT man_table FROM cat_feature_arc c JOIN sys_feature_cat s ON c.type = s.id + v_man_table := (SELECT man_table FROM cat_feature_arc c JOIN sys_feature_cat s ON c.type = s.id JOIN cat_arc ON c.id = cat_arc.arctype_id WHERE cat_arc.id=NEW.arccat_id); IF v_man_table IS NOT NULL THEN - v_sql:= 'INSERT INTO '||v_man_table||' (arc_id) VALUES ('||quote_literal(NEW.arc_id)||')'; + v_sql:= 'INSERT INTO '||v_man_table||' (arc_id) VALUES ('||quote_literal(NEW.arc_id)||')'; EXECUTE v_sql; - END IF; + END IF; END IF; -- childtable insert @@ -460,17 +461,20 @@ BEGIN USING NEW INTO v_new_value_param; - IF v_new_value_param IS NOT NULL THEN - EXECUTE 'INSERT INTO man_arc_'||lower(v_customfeature)||' (arc_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||')' - USING NEW.arc_id, v_new_value_param; + v_childtable_name := 'man_arc_' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + IF v_new_value_param IS NOT NULL THEN + EXECUTE 'INSERT INTO '||v_childtable_name||' (arc_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||')' + USING NEW.arc_id, v_new_value_param; + END IF; END IF; END LOOP; END IF; -- EPA INSERT - IF (NEW.epa_type = 'PIPE') THEN + IF (NEW.epa_type = 'PIPE') THEN v_inp_table:= 'inp_pipe'; - + ELSIF (NEW.epa_type = 'VIRTUALPUMP') THEN v_inp_table:= 'inp_virtualpump'; @@ -478,15 +482,15 @@ BEGIN v_inp_table:= 'inp_virtualvalve'; END IF; - + IF v_inp_table IS NOT NULL THEN v_sql:= 'INSERT INTO '||v_inp_table||' (arc_id) VALUES ('||quote_literal(NEW.arc_id)||')'; EXECUTE v_sql; END IF; - + --in case a project is dhc, insert cable IF (SELECT value FROM config_param_system WHERE parameter='dhc_plugin_version') is not null then - IF (SELECT value::boolean FROM config_param_user WHERE parameter='dhc_edit_insert_cable' + IF (SELECT value::boolean FROM config_param_user WHERE parameter='dhc_edit_insert_cable' AND cur_user=current_user) is true AND (SELECT json_extract_path_text(value::json,'cableFeaturecat') FROM config_param_system WHERE parameter='dhc_edit_insert_cable') != NEW.arc_type THEN raise notice 'execute'; @@ -499,7 +503,7 @@ BEGIN END IF; RETURN NEW; - + ELSIF TG_OP = 'UPDATE' THEN -- this overwrites triger topocontrol arc values (triggered before insertion) just in that moment: In order to make more profilactic this issue only will be overwrited in case of NEW.node_* not nulls @@ -513,7 +517,7 @@ BEGIN END IF; -- epa type - IF (NEW.epa_type != OLD.epa_type) THEN + IF (NEW.epa_type != OLD.epa_type) THEN -- delete from old inp table IF (OLD.epa_type = 'PIPE') THEN @@ -527,7 +531,7 @@ BEGIN v_sql:= 'DELETE FROM '||v_inp_table||' WHERE arc_id = '||quote_literal(OLD.arc_id); EXECUTE v_sql; END IF; - + v_inp_table := NULL; -- insert into new inp table @@ -539,7 +543,7 @@ BEGIN INSERT INTO inp_virtualpump (arc_id, status) VALUES (NEW.arc_id, 'ACTIVE') ON CONFLICT (arc_id) DO NOTHING; END IF; END IF; - + -- State IF (NEW.state != OLD.state) THEN UPDATE arc SET state=NEW.state WHERE arc_id = OLD.arc_id; @@ -549,13 +553,13 @@ BEGIN = 'plan_psector_vdefault'::text AND config_param_user.cur_user::name = "current_user"() LIMIT 1), 1, true); END IF; IF NEW.state = 1 AND OLD.state=2 THEN - DELETE FROM plan_psector_x_arc WHERE arc_id=NEW.arc_id; - END IF; + DELETE FROM plan_psector_x_arc WHERE arc_id=NEW.arc_id; + END IF; IF NEW.state=0 THEN UPDATE arc SET node_1=NULL, node_2=NULL WHERE arc_id = OLD.arc_id; END IF; END IF; - + -- State_type IF NEW.state=0 AND OLD.state=1 THEN IF (SELECT state FROM value_state_type WHERE id=NEW.state_type) != NEW.state THEN @@ -575,8 +579,8 @@ BEGIN IF (NEW.state_type != OLD.state_type) AND NEW.state_type NOT IN (SELECT id FROM value_state_type WHERE state = NEW.state) THEN EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, "data":{"message":"3036", "function":"1318","debug_msg":"'||NEW.state::text||'"}}$$);'; - END IF; - + END IF; + -- The geom IF st_orderingequals(NEW.the_geom, OLD.the_geom) IS FALSE OR NEW.node_1 IS NULL OR NEW.node_2 IS NULL THEN UPDATE arc SET the_geom=NEW.the_geom WHERE arc_id = OLD.arc_id; @@ -584,7 +588,7 @@ BEGIN --link_path SELECT link_path INTO v_link_path FROM cat_feature JOIN cat_arc ON cat_arc.arctype_id=cat_feature.id WHERE cat_arc.id=NEW.arccat_id; - + IF v_link_path IS NOT NULL THEN NEW.link = replace(NEW.link, v_link_path,''); END IF; @@ -604,18 +608,18 @@ BEGIN END IF; UPDATE arc - SET code=NEW.code, arccat_id=NEW.arccat_id, epa_type=NEW.epa_type, sector_id=NEW.sector_id, state_type=NEW.state_type, annotation= NEW.annotation, "observ"=NEW.observ, + SET code=NEW.code, arccat_id=NEW.arccat_id, epa_type=NEW.epa_type, sector_id=NEW.sector_id, state_type=NEW.state_type, annotation= NEW.annotation, "observ"=NEW.observ, "comment"=NEW.comment, custom_length=NEW.custom_length, dma_id=NEW.dma_id, presszone_id=NEW.presszone_id, soilcat_id=NEW.soilcat_id, function_type=NEW.function_type, category_type=NEW.category_type, fluid_type=NEW.fluid_type, location_type=NEW.location_type, workcat_id=NEW.workcat_id, workcat_id_end=NEW.workcat_id_end, workcat_id_plan=NEW.workcat_id_plan, - buildercat_id=NEW.buildercat_id, builtdate=NEW.builtdate, enddate=NEW.enddate, ownercat_id=NEW.ownercat_id, muni_id=NEW.muni_id, streetaxis_id=v_streetaxis, - streetaxis2_id=v_streetaxis2,postcode=NEW.postcode, district_id = NEW.district_id, postnumber=NEW.postnumber, postnumber2=NEW.postnumber2,descript=NEW.descript, verified=NEW.verified, + buildercat_id=NEW.buildercat_id, builtdate=NEW.builtdate, enddate=NEW.enddate, ownercat_id=NEW.ownercat_id, muni_id=NEW.muni_id, streetaxis_id=v_streetaxis, + streetaxis2_id=v_streetaxis2,postcode=NEW.postcode, district_id = NEW.district_id, postnumber=NEW.postnumber, postnumber2=NEW.postnumber2,descript=NEW.descript, verified=NEW.verified, undelete=NEW.undelete, label_x=NEW.label_x, - postcomplement=NEW.postcomplement, postcomplement2=NEW.postcomplement2,label_y=NEW.label_y,label_rotation=NEW.label_rotation, publish=NEW.publish, inventory=NEW.inventory, + postcomplement=NEW.postcomplement, postcomplement2=NEW.postcomplement2,label_y=NEW.label_y,label_rotation=NEW.label_rotation, publish=NEW.publish, inventory=NEW.inventory, expl_id=NEW.expl_id,num_value=NEW.num_value, link=NEW.link, lastupdate=now(), lastupdate_user=current_user, depth=NEW.depth, adate=NEW.adate, adescript=NEW.adescript, asset_id=NEW.asset_id, pavcat_id=NEW.pavcat_id, om_state=NEW.om_state, conserv_state=NEW.conserv_state, parent_id = NEW.parent_id,expl_id2 =NEW.expl_id2, brand_id=NEW.brand_id, model_id=NEW.model_id, serial_number=NEW.serial_number WHERE arc_id=OLD.arc_id; - + -- childtable update IF v_customfeature IS NOT NULL THEN FOR v_addfields IN SELECT * FROM sys_addfields @@ -629,15 +633,18 @@ BEGIN USING OLD INTO v_old_value_param; - IF (v_new_value_param IS NOT NULL AND v_old_value_param!=v_new_value_param) OR (v_new_value_param IS NOT NULL AND v_old_value_param IS NULL) THEN - EXECUTE 'INSERT INTO man_arc_'||lower(v_customfeature)||' (arc_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||') - ON CONFLICT (arc_id) - DO UPDATE SET '||v_addfields.param_name||'=$2::'||v_addfields.datatype_id||' WHERE man_arc_'||lower(v_customfeature)||'.arc_id=$1' - USING NEW.arc_id, v_new_value_param; - - ELSIF v_new_value_param IS NULL AND v_old_value_param IS NOT NULL THEN - EXECUTE 'UPDATE man_arc_'||lower(v_customfeature)||' SET '||v_addfields.param_name||' = null WHERE man_arc_'||lower(v_customfeature)||'.arc_id=$1' - USING NEW.arc_id; + v_childtable_name := 'man_arc_' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + IF (v_new_value_param IS NOT NULL AND v_old_value_param!=v_new_value_param) OR (v_new_value_param IS NOT NULL AND v_old_value_param IS NULL) THEN + EXECUTE 'INSERT INTO '||v_childtable_name||' (arc_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||') + ON CONFLICT (arc_id) + DO UPDATE SET '||v_addfields.param_name||'=$2::'||v_addfields.datatype_id||' WHERE '||v_childtable_name||'.arc_id=$1' + USING NEW.arc_id, v_new_value_param; + + ELSIF v_new_value_param IS NULL AND v_old_value_param IS NOT NULL THEN + EXECUTE 'UPDATE '||v_childtable_name||' SET '||v_addfields.param_name||' = null WHERE '||v_childtable_name||'.arc_id=$1' + USING NEW.arc_id; + END IF; END IF; END LOOP; END IF; @@ -653,30 +660,33 @@ BEGIN RETURN NEW; - ELSIF TG_OP = 'DELETE' THEN - + ELSIF TG_OP = 'DELETE' THEN + EXECUTE 'SELECT gw_fct_getcheckdelete($${"client":{"device":4, "infoType":1, "lang":"ES"}, "feature":{"id":"'||OLD.arc_id||'","featureType":"ARC"}, "data":{}}$$)'; -- force plan_psector_force_delete SELECT value INTO v_force_delete FROM config_param_user WHERE parameter = 'plan_psector_force_delete' and cur_user = current_user; UPDATE config_param_user SET value = 'true' WHERE parameter = 'plan_psector_force_delete' and cur_user = current_user; - + DELETE FROM arc WHERE arc_id = OLD.arc_id; -- restore plan_psector_force_delete UPDATE config_param_user SET value = v_force_delete WHERE parameter = 'plan_psector_force_delete' and cur_user = current_user; - + -- Delete childtable addfields (after or before deletion of node, doesn't matter) - + v_customfeature = old.arc_type; v_arc_id = old.arc_id; - - EXECUTE 'DELETE FROM man_arc_'||lower(v_customfeature)||' WHERE arc_id = '||quote_literal(v_arc_id)||''; + + v_childtable_name := 'man_arc_' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + EXECUTE 'DELETE FROM '||v_childtable_name||' WHERE arc_id = '||quote_literal(v_arc_id)||''; + END IF; -- delete from arc_add table DELETE FROM arc_add WHERE arc_id = OLD.arc_id; - + RETURN NULL; END IF; @@ -684,4 +694,3 @@ END; $BODY$ LANGUAGE plpgsql VOLATILE COST 100; - \ No newline at end of file diff --git a/ws/ftrg/ws_gw_trg_edit_connec.sql b/ws/ftrg/ws_gw_trg_edit_connec.sql index 4ec8ba5438..6dddb59549 100644 --- a/ws/ftrg/ws_gw_trg_edit_connec.sql +++ b/ws/ftrg/ws_gw_trg_edit_connec.sql @@ -11,10 +11,10 @@ CREATE OR REPLACE FUNCTION "SCHEMA_NAME".gw_trg_edit_connec() RETURNS trigger AS $BODY$ -DECLARE +DECLARE v_sql varchar; -v_man_table varchar; +v_man_table varchar; v_code_autofill_bool boolean; v_type_man_table varchar; v_promixity_buffer double precision; @@ -55,19 +55,20 @@ v_seq_name text; v_seq_code text; v_code_prefix text; v_connec_id text; +v_childtable_name text; BEGIN EXECUTE 'SET search_path TO '||quote_literal(TG_TABLE_SCHEMA)||', public'; v_man_table:= TG_ARGV[0]; - + IF v_man_table IN (SELECT id FROM cat_feature WHERE feature_type = 'CONNEC') THEN v_customfeature:=v_man_table; v_man_table:=(SELECT man_table FROM cat_feature_connec c JOIN sys_feature_cat s ON c.type = s.id WHERE c.id=v_man_table); END IF; - + v_type_man_table:=v_man_table; - + -- get system and user variables v_promixity_buffer = (SELECT "value" FROM config_param_system WHERE parameter='edit_feature_buffer_on_mapzone'); SELECT ((value::json)->>'activated') INTO v_insert_double_geom FROM config_param_system WHERE parameter='insert_double_geometry'; @@ -87,19 +88,19 @@ BEGIN v_psector_vdefault = (SELECT config_param_user.value::integer AS value FROM config_param_user WHERE config_param_user.parameter::text = 'plan_psector_vdefault'::text AND config_param_user.cur_user::name = "current_user"() LIMIT 1); - + IF TG_OP = 'INSERT' OR TG_OP = 'UPDATE' THEN - + -- check if streetname exists IF NEW.streetname IS NOT NULL AND ((NEW.streetname NOT IN (SELECT DISTINCT descript FROM v_ext_streetaxis)) OR (NEW.streetname2 NOT IN (SELECT DISTINCT descript FROM v_ext_streetaxis))) THEN EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, "data":{"message":"3246", "function":"1304","debug_msg":null}}$$);'; END IF; - + -- transforming streetaxis name into id v_streetaxis = (SELECT id FROM v_ext_streetaxis WHERE (muni_id = NEW.muni_id OR muni_id IS NULL) AND descript = NEW.streetname LIMIT 1); v_streetaxis2 = (SELECT id FROM v_ext_streetaxis WHERE (muni_id = NEW.muni_id OR muni_id IS NULL) AND descript = NEW.streetname2 LIMIT 1); - + -- check arc exploitation IF NEW.arc_id IS NOT NULL AND NEW.expl_id IS NOT NULL THEN IF (SELECT expl_id FROM arc WHERE arc_id = NEW.arc_id) != NEW.expl_id THEN @@ -109,11 +110,11 @@ BEGIN "data":{"message":"3144", "function":"1304","debug_msg":"'||NEW.arc_id::text||'"}}$$);'; ELSE SELECT concat('ERROR-',id,':',error_message,'.',hint_message) INTO v_message FROM sys_message WHERE id = 3144; - INSERT INTO audit_log_data (fid, feature_id, log_message) VALUES (394, NEW.connec_id, v_message); + INSERT INTO audit_log_data (fid, feature_id, log_message) VALUES (394, NEW.connec_id, v_message); END IF; END IF; END IF; - + -- setting pjoint_id, pjoint_type and arc_id and removing link in case of connec is over arc v_arc_id = (SELECT arc_id FROM v_edit_arc WHERE st_dwithin(the_geom, NEW.the_geom, 0.01) AND state > 0 LIMIT 1); IF v_arc_id IS NOT NULL THEN @@ -123,7 +124,7 @@ BEGIN DELETE FROM link WHERE feature_id = NEW.connec_id; END IF; END IF; - + -- Control insertions ID IF TG_OP = 'INSERT' THEN @@ -136,7 +137,7 @@ BEGIN IF NEW.connec_id != (SELECT last_value::text FROM urn_id_seq) OR NEW.connec_id IS NULL THEN NEW.connec_id = (SELECT nextval('urn_id_seq')); END IF; - + -- connec Catalog ID IF (NEW.connecat_id IS NULL) THEN IF ((SELECT COUNT(*) FROM cat_connec WHERE active IS TRUE) = 0) THEN @@ -153,66 +154,66 @@ BEGIN IF (NEW.connecat_id IS NULL) THEN EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, "data":{"message":"1086", "function":"1304","debug_msg":null, "variables":null}}$$);'; - END IF; + END IF; END IF; - + -- Exploitation IF (NEW.expl_id IS NULL) THEN - + -- control error without any mapzones defined on the table of mapzone IF ((SELECT COUNT(*) FROM exploitation WHERE active IS TRUE) = 0) THEN EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, "data":{"message":"1110", "function":"1304","debug_msg":null}}$$);'; END IF; - + -- getting value default IF (NEW.expl_id IS NULL) THEN NEW.expl_id := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_exploitation_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + -- getting value from geometry of mapzone IF (NEW.expl_id IS NULL) THEN SELECT count(*) INTO v_count FROM exploitation WHERE ST_DWithin(NEW.the_geom, exploitation.the_geom,0.001) AND active IS TRUE; IF v_count = 1 THEN NEW.expl_id = (SELECT expl_id FROM exploitation WHERE ST_DWithin(NEW.the_geom, exploitation.the_geom,0.001) AND active IS TRUE LIMIT 1); ELSE - NEW.expl_id =(SELECT expl_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) + NEW.expl_id =(SELECT expl_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) order by ST_Distance (NEW.the_geom, v_edit_arc.the_geom) LIMIT 1); - END IF; + END IF; END IF; - + -- control error when no value IF (NEW.expl_id IS NULL) THEN EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, "data":{"message":"2012", "function":"1304","debug_msg":"'||NEW.connec_id::text||'"}}$$);'; - END IF; + END IF; END IF; - + -- Sector ID IF (NEW.sector_id IS NULL) THEN - + -- control error without any mapzones defined on the table of mapzone IF ((SELECT COUNT(*) FROM sector WHERE active IS TRUE ) = 0) THEN EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, "data":{"message":"1008", "function":"1304","debug_msg":null}}$$);'; END IF; - + -- getting value default IF (NEW.sector_id IS NULL) THEN NEW.sector_id := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_sector_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + -- getting value from geometry of mapzone IF (NEW.sector_id IS NULL) THEN SELECT count(*) INTO v_count FROM sector WHERE ST_DWithin(NEW.the_geom, sector.the_geom,0.001) AND active IS TRUE ; IF v_count = 1 THEN NEW.sector_id = (SELECT sector_id FROM sector WHERE ST_DWithin(NEW.the_geom, sector.the_geom,0.001) AND active IS TRUE LIMIT 1); ELSE - NEW.sector_id =(SELECT sector_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) + NEW.sector_id =(SELECT sector_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) order by ST_Distance (NEW.the_geom, v_edit_arc.the_geom) LIMIT 1); - END IF; + END IF; END IF; - + -- control when no value IF NEW.sector_id IS NULL THEN NEW.sector_id = 0; @@ -221,49 +222,49 @@ BEGIN -- Dma ID IF (NEW.dma_id IS NULL) THEN - + -- control error without any mapzones defined on the table of mapzone IF ((SELECT COUNT(*) FROM dma WHERE active IS TRUE ) = 0) THEN EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, "data":{"message":"1012", "function":"1304","debug_msg":null}}$$);'; END IF; - + -- getting value default IF (NEW.dma_id IS NULL) THEN NEW.dma_id := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_dma_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + -- getting value from geometry of mapzone IF (NEW.dma_id IS NULL) THEN SELECT count(*) INTO v_count FROM dma WHERE ST_DWithin(NEW.the_geom, dma.the_geom,0.001) AND active IS TRUE ; IF v_count = 1 THEN NEW.dma_id = (SELECT dma_id FROM dma WHERE ST_DWithin(NEW.the_geom, dma.the_geom,0.001) AND active IS TRUE LIMIT 1); ELSE - NEW.dma_id =(SELECT dma_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) + NEW.dma_id =(SELECT dma_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) order by ST_Distance (NEW.the_geom, v_edit_arc.the_geom) LIMIT 1); - END IF; + END IF; END IF; - + -- control when no value IF NEW.dma_id IS NULL THEN NEW.dma_id = 0; - END IF; + END IF; END IF; - + -- Presszone IF (NEW.presszone_id IS NULL) THEN - + -- control error without any mapzones defined on the table of mapzone IF ((SELECT COUNT(*) FROM presszone WHERE active IS TRUE ) = 0) THEN EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, "data":{"message":"3106", "function":"1304","debug_msg":null}}$$);'; END IF; - + -- getting value default IF (NEW.presszone_id IS NULL) THEN NEW.presszone_id := (SELECT "value" FROM config_param_user WHERE "parameter"='presszone_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + -- getting value from geometry of mapzone IF (NEW.presszone_id IS NULL) THEN SELECT count(*) INTO v_count FROM presszone WHERE ST_DWithin(NEW.the_geom, presszone.the_geom,0.001) AND active IS TRUE ; @@ -272,56 +273,56 @@ BEGIN ELSE NEW.presszone_id =(SELECT presszone_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) order by ST_Distance (NEW.the_geom, v_edit_arc.the_geom) LIMIT 1); - END IF; + END IF; END IF; - + -- control when no value IF NEW.presszone_id IS NULL THEN NEW.presszone_id = 0; - END IF; + END IF; END IF; - - -- Municipality + + -- Municipality IF (NEW.muni_id IS NULL) THEN - + -- getting value default IF (NEW.muni_id IS NULL) THEN NEW.muni_id := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_municipality_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + -- getting value from geometry of mapzone IF (NEW.muni_id IS NULL) THEN SELECT count(*) INTO v_count FROM ext_municipality WHERE ST_DWithin(NEW.the_geom, ext_municipality.the_geom,0.001) AND active IS TRUE ; IF v_count = 1 THEN - NEW.muni_id = (SELECT muni_id FROM ext_municipality WHERE ST_DWithin(NEW.the_geom, ext_municipality.the_geom,0.001) + NEW.muni_id = (SELECT muni_id FROM ext_municipality WHERE ST_DWithin(NEW.the_geom, ext_municipality.the_geom,0.001) AND active IS TRUE LIMIT 1); ELSE - NEW.muni_id =(SELECT muni_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) + NEW.muni_id =(SELECT muni_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) order by ST_Distance (NEW.the_geom, v_edit_arc.the_geom) LIMIT 1); - END IF; - END IF; + END IF; + END IF; END IF; - - -- District + + -- District IF (NEW.district_id IS NULL) THEN - + -- getting value from geometry of mapzone IF (NEW.district_id IS NULL) THEN SELECT count(*) INTO v_count FROM ext_district WHERE ST_DWithin(NEW.the_geom, ext_district.the_geom,0.001); IF v_count = 1 THEN NEW.district_id = (SELECT district_id FROM ext_district WHERE ST_DWithin(NEW.the_geom, ext_district.the_geom,0.001) LIMIT 1); ELSIF v_count > 1 THEN - NEW.district_id =(SELECT district_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) + NEW.district_id =(SELECT district_id FROM v_edit_arc WHERE ST_DWithin(NEW.the_geom, v_edit_arc.the_geom, v_promixity_buffer) order by ST_Distance (NEW.the_geom, v_edit_arc.the_geom) LIMIT 1); - END IF; - END IF; + END IF; + END IF; END IF; - + -- State IF (NEW.state IS NULL) THEN NEW.state := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_state_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + -- State_type IF (NEW.state=0) THEN IF (NEW.state_type IS NULL) THEN @@ -336,7 +337,7 @@ BEGIN NEW.state_type := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_statetype_2_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; END IF; - + --check relation state - state_type IF NEW.state_type NOT IN (SELECT id FROM value_state_type WHERE state = NEW.state) THEN IF NEW.state IS NOT NULL THEN @@ -344,7 +345,7 @@ BEGIN ELSE v_sql = 'null'; END IF; - + EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, "data":{"message":"3036", "function":"1318","debug_msg":"'||v_sql::text||'"}}$$);'; END IF; @@ -353,32 +354,32 @@ BEGIN IF NEW.inventory IS NULL THEN NEW.inventory := (SELECT "value" FROM config_param_system WHERE "parameter"='edit_inventory_sysvdefault'); END IF; - + --Publish IF NEW.publish IS NULL THEN NEW.publish := (SELECT "value" FROM config_param_system WHERE "parameter"='edit_publish_sysvdefault'); - END IF; - + END IF; + -- Workcat_id IF (NEW.workcat_id IS NULL) THEN NEW.workcat_id := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_workcat_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + --Workcat_id_plan IF (NEW.workcat_id_plan IS NULL AND NEW.state = 2) THEN NEW.workcat_id_plan := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_workcat_id_plan' AND "cur_user"="current_user"() LIMIT 1); END IF; - + -- Ownercat_id IF (NEW.ownercat_id IS NULL) THEN NEW.ownercat_id := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_ownercat_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + -- Soilcat_id IF (NEW.soilcat_id IS NULL) THEN NEW.soilcat_id := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_soilcat_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; - + --Builtdate IF (NEW.builtdate IS NULL) THEN NEW.builtdate :=(SELECT "value" FROM config_param_user WHERE "parameter"='edit_builtdate_vdefault' AND "cur_user"="current_user"() LIMIT 1); @@ -386,10 +387,10 @@ BEGIN NEW.builtdate :=date(now()); END IF; END IF; - + --Address - IF (v_streetaxis IS NULL) THEN - IF (v_auto_streetvalues_status is true) THEN + IF (v_streetaxis IS NULL) THEN + IF (v_auto_streetvalues_status is true) THEN v_streetaxis := (select v_ext_streetaxis.id from v_ext_streetaxis join node on ST_DWithin(NEW.the_geom, v_ext_streetaxis.the_geom, v_auto_streetvalues_buffer) order by ST_Distance(NEW.the_geom, v_ext_streetaxis.the_geom) LIMIT 1); @@ -397,7 +398,7 @@ BEGIN END IF; --Postnumber/postcomplement - IF (v_auto_streetvalues_status) IS TRUE THEN + IF (v_auto_streetvalues_status) IS TRUE THEN IF (v_auto_streetvalues_field = 'postcomplement') THEN IF (NEW.postcomplement IS NULL) THEN NEW.postcomplement = (select ext_address.postnumber from ext_address @@ -411,31 +412,31 @@ BEGIN order by ST_Distance(NEW.the_geom, ext_address.the_geom) LIMIT 1); END IF; END IF; - END IF; - + END IF; + -- Verified IF (NEW.verified IS NULL) THEN NEW.verified := (SELECT "value" FROM config_param_user WHERE "parameter"='edit_verified_vdefault' AND "cur_user"="current_user"() LIMIT 1); END IF; -- Code - SELECT code_autofill, cat_feature.id, addparam::json->>'code_prefix' INTO v_code_autofill_bool, v_featurecat, v_code_prefix FROM cat_feature + SELECT code_autofill, cat_feature.id, addparam::json->>'code_prefix' INTO v_code_autofill_bool, v_featurecat, v_code_prefix FROM cat_feature join cat_connec on cat_feature.id=cat_connec.connectype_id where cat_connec.id=NEW.connecat_id; - + -- use specific sequence for code when its name matches featurecat_code_seq EXECUTE 'SELECT concat('||quote_literal(lower(v_featurecat))||',''_code_seq'');' INTO v_seq_name; EXECUTE 'SELECT relname FROM pg_catalog.pg_class WHERE relname='||quote_literal(v_seq_name)||';' INTO v_sql; - + IF v_sql IS NOT NULL AND NEW.code IS NULL THEN EXECUTE 'SELECT nextval('||quote_literal(v_seq_name)||');' INTO v_seq_code; NEW.code=concat(v_code_prefix,v_seq_code); END IF; - + --Copy id to code field - IF (v_code_autofill_bool IS TRUE) AND NEW.code IS NULL THEN + IF (v_code_autofill_bool IS TRUE) AND NEW.code IS NULL THEN NEW.code=NEW.connec_id; - END IF; - + END IF; + -- LINK --google maps style IF (SELECT (value::json->>'google_maps')::boolean FROM config_param_system WHERE parameter='edit_custom_link') IS TRUE THEN @@ -445,12 +446,12 @@ BEGIN NEW.link=NEW.connec_id; END IF; - -- Customer code + -- Customer code IF NEW.customer_code IS NULL AND (SELECT (value::json->>'status')::boolean FROM config_param_system WHERE parameter = 'edit_connec_autofill_ccode') IS TRUE AND (SELECT (value::json->>'field')::text FROM config_param_system WHERE parameter = 'edit_connec_autofill_ccode')='code' THEN - + NEW.customer_code = NEW.code; - + ELSIF NEW.customer_code IS NULL AND (SELECT (value::json->>'status')::boolean FROM config_param_system WHERE parameter = 'edit_connec_autofill_ccode') IS TRUE AND (SELECT (value::json->>'field')::text FROM config_param_system WHERE parameter = 'edit_connec_autofill_ccode')='connec_id' THEN @@ -480,7 +481,7 @@ BEGIN IF NEW.fluid_type IS NULL THEN NEW.fluid_type = (SELECT value FROM config_param_user WHERE parameter = 'connec_fluid_vdefault' AND cur_user = current_user); - END IF; + END IF; --Category type IF NEW.category_type IS NULL AND (SELECT value FROM config_param_user WHERE parameter = 'edit_feature_category_vdefault' AND cur_user = current_user) = v_featurecat THEN @@ -489,7 +490,7 @@ BEGIN IF NEW.category_type IS NULL THEN NEW.category_type = (SELECT value FROM config_param_user WHERE parameter = 'connec_category_vdefault' AND cur_user = current_user); - END IF; + END IF; --Function type IF NEW.function_type IS NULL AND (SELECT value FROM config_param_user WHERE parameter = 'edit_feature_function_vdefault' AND cur_user = current_user) = v_featurecat THEN @@ -500,17 +501,17 @@ BEGIN NEW.function_type = (SELECT value FROM config_param_user WHERE parameter = 'connec_function_vdefault' AND cur_user = current_user); END IF; - -- crmzone_id + -- crmzone_id IF (NEW.crmzone_id IS NULL) THEN -- getting value from geometry of mapzone IF (NEW.crmzone_id IS NULL) THEN SELECT count(*) INTO v_count FROM crm_zone WHERE ST_DWithin(NEW.the_geom, crm_zone.the_geom,0.001); - NEW.crmzone_id = (SELECT id FROM crm_zone WHERE ST_DWithin(NEW.the_geom, crm_zone.the_geom,0.001) LIMIT 1); - END IF; + NEW.crmzone_id = (SELECT id FROM crm_zone WHERE ST_DWithin(NEW.the_geom, crm_zone.the_geom,0.001) LIMIT 1); + END IF; END IF; --elevation from raster - IF (SELECT json_extract_path_text(value::json,'activated')::boolean FROM config_param_system WHERE parameter='admin_raster_dem') IS TRUE + IF (SELECT json_extract_path_text(value::json,'activated')::boolean FROM config_param_system WHERE parameter='admin_raster_dem') IS TRUE AND (NEW.elevation IS NULL) AND (SELECT upper(value) FROM config_param_user WHERE parameter = 'edit_insert_elevation_from_dem' and cur_user = current_user) = 'TRUE' THEN NEW.elevation = (SELECT ST_Value(rast,1,NEW.the_geom,true) FROM v_ext_raster_dem WHERE id = @@ -528,59 +529,59 @@ BEGIN -- FEATURE INSERT INSERT INTO connec (connec_id, code, elevation, depth,connecat_id, sector_id, customer_code, state, state_type, annotation, observ, comment,dma_id, presszone_id, soilcat_id, - function_type, category_type, fluid_type, location_type, workcat_id, workcat_id_end, workcat_id_plan, buildercat_id, builtdate, enddate, ownercat_id, streetaxis_id, postnumber, postnumber2, + function_type, category_type, fluid_type, location_type, workcat_id, workcat_id_end, workcat_id_plan, buildercat_id, builtdate, enddate, ownercat_id, streetaxis_id, postnumber, postnumber2, muni_id, streetaxis2_id, postcode, district_id, postcomplement, postcomplement2, descript, link, verified, rotation, the_geom, undelete, label_x,label_y,label_rotation, expl_id, publish, inventory,num_value, connec_length, arc_id, minsector_id, dqa_id, pjoint_id, pjoint_type, - adate, adescript, accessibility, lastupdate, lastupdate_user, asset_id, epa_type, om_state, conserv_state, priority, + adate, adescript, accessibility, lastupdate, lastupdate_user, asset_id, epa_type, om_state, conserv_state, priority, valve_location, valve_type, shutoff_valve, access_type, placement_type, crmzone_id, expl_id2, plot_code, brand_id, model_id, serial_number, cat_valve) - VALUES (NEW.connec_id, NEW.code, NEW.elevation, NEW.depth, NEW.connecat_id, NEW.sector_id, NEW.customer_code, NEW.state, NEW.state_type, NEW.annotation, NEW.observ, NEW.comment, + VALUES (NEW.connec_id, NEW.code, NEW.elevation, NEW.depth, NEW.connecat_id, NEW.sector_id, NEW.customer_code, NEW.state, NEW.state_type, NEW.annotation, NEW.observ, NEW.comment, NEW.dma_id, NEW.presszone_id, NEW.soilcat_id, NEW.function_type, NEW.category_type, NEW.fluid_type, NEW.location_type, NEW.workcat_id, NEW.workcat_id_end, NEW.workcat_id_plan, NEW.buildercat_id, - NEW.builtdate, NEW.enddate, NEW.ownercat_id, v_streetaxis, NEW.postnumber, NEW.postnumber2, NEW.muni_id, v_streetaxis2, NEW.postcode, NEW.district_id, NEW.postcomplement, - NEW.postcomplement2, NEW.descript, NEW.link, NEW.verified, NEW.rotation, NEW.the_geom,NEW.undelete,NEW.label_x, NEW.label_y,NEW.label_rotation, NEW.expl_id, NEW.publish, NEW.inventory, + NEW.builtdate, NEW.enddate, NEW.ownercat_id, v_streetaxis, NEW.postnumber, NEW.postnumber2, NEW.muni_id, v_streetaxis2, NEW.postcode, NEW.district_id, NEW.postcomplement, + NEW.postcomplement2, NEW.descript, NEW.link, NEW.verified, NEW.rotation, NEW.the_geom,NEW.undelete,NEW.label_x, NEW.label_y,NEW.label_rotation, NEW.expl_id, NEW.publish, NEW.inventory, NEW.num_value, NEW.connec_length, NEW.arc_id, NEW.minsector_id, NEW.dqa_id, NEW.pjoint_id, NEW.pjoint_type, NEW.adate, NEW.adescript, NEW.accessibility, NEW.lastupdate, NEW.lastupdate_user, NEW.asset_id, NEW.epa_type, NEW.om_state, NEW.conserv_state, NEW.priority, NEW.valve_location, NEW.valve_type, NEW.shutoff_valve, NEW.access_type, NEW.placement_type, NEW.crmzone_id, NEW.expl_id2, NEW.plot_code, NEW.brand_id, NEW.model_id, NEW.serial_number, NEW.cat_valve); - - SELECT system_id, cat_feature.id INTO v_system_id, v_featurecat_id FROM cat_feature + + SELECT system_id, cat_feature.id INTO v_system_id, v_featurecat_id FROM cat_feature JOIN cat_connec ON cat_feature.id=connectype_id where cat_connec.id=NEW.connecat_id; EXECUTE 'SELECT json_extract_path_text(double_geom,''activated'')::boolean, json_extract_path_text(double_geom,''value'') FROM cat_feature_connec WHERE id='||quote_literal(v_featurecat_id)||'' INTO v_insert_double_geom, v_double_geom_buffer; - IF (v_insert_double_geom IS TRUE) THEN - INSERT INTO polygon(sys_type, the_geom, featurecat_id, feature_id ) - VALUES (v_system_id, (SELECT ST_Multi(ST_Envelope(ST_Buffer(connec.the_geom,v_double_geom_buffer))) + IF (v_insert_double_geom IS TRUE) THEN + INSERT INTO polygon(sys_type, the_geom, featurecat_id, feature_id ) + VALUES (v_system_id, (SELECT ST_Multi(ST_Envelope(ST_Buffer(connec.the_geom,v_double_geom_buffer))) from connec where connec_id=NEW.connec_id), v_featurecat_id, NEW.connec_id); END IF; IF v_man_table='man_greentap' THEN - INSERT INTO man_greentap (connec_id, linked_connec, greentap_type) - VALUES(NEW.connec_id, NEW.linked_connec, NEW.greentap_type); - - ELSIF v_man_table='man_fountain' THEN - - INSERT INTO man_fountain(connec_id, linked_connec, vmax, vtotal, container_number, pump_number, power, regulation_tank,name, - chlorinator, arq_patrimony) - VALUES (NEW.connec_id, NEW.linked_connec, NEW.vmax, NEW.vtotal,NEW.container_number, NEW.pump_number, NEW.power, NEW.regulation_tank, NEW.name, + INSERT INTO man_greentap (connec_id, linked_connec, greentap_type) + VALUES(NEW.connec_id, NEW.linked_connec, NEW.greentap_type); + + ELSIF v_man_table='man_fountain' THEN + + INSERT INTO man_fountain(connec_id, linked_connec, vmax, vtotal, container_number, pump_number, power, regulation_tank,name, + chlorinator, arq_patrimony) + VALUES (NEW.connec_id, NEW.linked_connec, NEW.vmax, NEW.vtotal,NEW.container_number, NEW.pump_number, NEW.power, NEW.regulation_tank, NEW.name, NEW.chlorinator, NEW.arq_patrimony); - - ELSIF v_man_table='man_tap' THEN - INSERT INTO man_tap(connec_id, linked_connec, drain_diam, drain_exit, drain_gully, drain_distance, arq_patrimony, com_state) + + ELSIF v_man_table='man_tap' THEN + INSERT INTO man_tap(connec_id, linked_connec, drain_diam, drain_exit, drain_gully, drain_distance, arq_patrimony, com_state) VALUES (NEW.connec_id, NEW.linked_connec, NEW.drain_diam, NEW.drain_exit, NEW.drain_gully, NEW.drain_distance, NEW.arq_patrimony, NEW.com_state); - - ELSIF v_man_table='man_wjoin' THEN - INSERT INTO man_wjoin (connec_id, top_floor,wjoin_type) + + ELSIF v_man_table='man_wjoin' THEN + INSERT INTO man_wjoin (connec_id, top_floor,wjoin_type) VALUES (NEW.connec_id, NEW.top_floor, NEW.wjoin_type); - - END IF; + + END IF; IF v_man_table='parent' THEN v_man_table:= (SELECT man_table FROM cat_feature_connec c JOIN sys_feature_cat s ON c.type = s.id JOIN cat_connec ON cat_connec.id=NEW.connecat_id WHERE c.id = cat_connec.connectype_id LIMIT 1)::text; - + IF v_man_table IS NOT NULL THEN v_sql:= 'INSERT INTO '||v_man_table||' (connec_id) VALUES ('||quote_literal(NEW.connec_id)||')'; EXECUTE v_sql; @@ -595,7 +596,7 @@ BEGIN -- manage connect2network IF v_connect2network THEN - + IF NEW.arc_id IS NOT NULL THEN EXECUTE 'SELECT gw_fct_linktonetwork($${"client":{"device":4, "infoType":1, "lang":"ES"}, "feature":{"id":'|| array_to_json(array_agg(NEW.connec_id))||'},"data":{"feature_type":"CONNEC", "forcedArcs":["'||NEW.arc_id||'"]}}$$)'; @@ -606,8 +607,8 @@ BEGIN -- recover values in order to do not disturb this workflow SELECT * INTO v_arc FROM arc WHERE arc_id = NEW.arc_id; - NEW.pjoint_id = v_arc.arc_id; NEW.pjoint_type = 'ARC'; NEW.sector_id = v_arc.sector_id; NEW.dma_id = v_arc.dma_id; - NEW.presszone_id = v_arc.presszone_id; NEW.dqa_id = v_arc.dqa_id; NEW.minsector_id = v_arc.minsector_id; + NEW.pjoint_id = v_arc.arc_id; NEW.pjoint_type = 'ARC'; NEW.sector_id = v_arc.sector_id; NEW.dma_id = v_arc.dma_id; + NEW.presszone_id = v_arc.presszone_id; NEW.dqa_id = v_arc.dqa_id; NEW.minsector_id = v_arc.minsector_id; END IF; -- childtable insert @@ -619,40 +620,43 @@ BEGIN USING NEW INTO v_new_value_param; - IF v_new_value_param IS NOT NULL THEN - EXECUTE 'INSERT INTO man_connec_'||lower(v_customfeature)||' (connec_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||')' - USING NEW.connec_id, v_new_value_param; + v_childtable_name := 'man_connec' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + IF v_new_value_param IS NOT NULL THEN + EXECUTE 'INSERT INTO '||v_childtable_name||' (connec_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||')' + USING NEW.connec_id, v_new_value_param; + END IF; END IF; END LOOP; END IF; -- epa insert - IF (NEW.epa_type = 'JUNCTION') THEN + IF (NEW.epa_type = 'JUNCTION') THEN INSERT INTO inp_connec (connec_id) VALUES (NEW.connec_id); END IF; - + -- static pressure IF v_ispresszone AND NEW.presszone_id IS NOT NULL THEN UPDATE connec SET staticpressure = (SELECT head from presszone WHERE presszone_id = NEW.presszone_id)-elevation WHERE connec_id = NEW.connec_id; END IF; - + RETURN NEW; - + ELSIF TG_OP = 'UPDATE' THEN - + -- static pressure IF v_ispresszone AND (NEW.presszone_id != OLD.presszone_id) THEN raise notice '2 NEW.presszone_id ---> %', NEW.presszone_id; - UPDATE connec SET staticpressure = (SELECT head from presszone WHERE presszone_id = NEW.presszone_id)-elevation + UPDATE connec SET staticpressure = (SELECT head from presszone WHERE presszone_id = NEW.presszone_id)-elevation WHERE connec_id = NEW.connec_id; END IF; -- EPA update - IF (NEW.epa_type != OLD.epa_type) THEN + IF (NEW.epa_type != OLD.epa_type) THEN IF NEW.epa_type = 'UNDEFINED' THEN DELETE FROM inp_connec WHERE connec_id = NEW.connec_id; ELSIF NEW.epa_type = 'JUNCTION' THEN - INSERT INTO inp_connec (connec_id) VALUES (NEW.connec_id) + INSERT INTO inp_connec (connec_id) VALUES (NEW.connec_id) ON CONFLICT (connec_id) DO NOTHING; END IF; END IF; @@ -662,19 +666,19 @@ BEGIN UPDATE connec SET the_geom=NEW.the_geom WHERE connec_id = OLD.connec_id; --update elevation from raster - IF (SELECT json_extract_path_text(value::json,'activated')::boolean FROM config_param_system WHERE parameter='admin_raster_dem') IS TRUE + IF (SELECT json_extract_path_text(value::json,'activated')::boolean FROM config_param_system WHERE parameter='admin_raster_dem') IS TRUE AND (NEW.elevation = OLD.elevation) AND (SELECT upper(value) FROM config_param_user WHERE parameter = 'edit_update_elevation_from_dem' and cur_user = current_user) = 'TRUE' THEN NEW.elevation = (SELECT ST_Value(rast,1,NEW.the_geom,true) FROM v_ext_raster_dem WHERE id = (SELECT id FROM v_ext_raster_dem WHERE st_dwithin (envelope, NEW.the_geom, 1) LIMIT 1)); - END IF; - + END IF; + --update associated geometry of element (if exists) and trace_featuregeom is true v_trace_featuregeom:= (SELECT trace_featuregeom FROM element JOIN element_x_connec using (element_id) WHERE connec_id=NEW.connec_id AND the_geom IS NOT NULL LIMIT 1); - + -- if trace_featuregeom is false, do nothing IF v_trace_featuregeom IS TRUE THEN - UPDATE v_edit_element SET the_geom = NEW.the_geom WHERE St_dwithin(OLD.the_geom, the_geom, 0.001) + UPDATE v_edit_element SET the_geom = NEW.the_geom WHERE St_dwithin(OLD.the_geom, the_geom, 0.001) AND element_id IN (SELECT element_id FROM element_x_connec WHERE connec_id=NEW.connec_id); END IF; @@ -690,13 +694,13 @@ BEGIN IF (SELECT value::boolean FROM config_param_system WHERE parameter = 'edit_connec_autofill_plotcode') = TRUE THEN NEW.plot_code = (SELECT plot_code FROM v_ext_plot WHERE st_dwithin(the_geom, NEW.the_geom, 0) LIMIT 1); END IF; - + ELSIF st_equals( NEW.the_geom, OLD.the_geom) IS FALSE AND geometrytype(NEW.the_geom)='MULTIPOLYGON' THEN UPDATE polygon SET the_geom=NEW.the_geom WHERE pol_id = OLD.pol_id; - NEW.sector_id:= (SELECT sector_id FROM sector WHERE ST_DWithin(NEW.the_geom, sector.the_geom,0.001) LIMIT 1); - NEW.dma_id := (SELECT dma_id FROM dma WHERE ST_DWithin(NEW.the_geom, dma.the_geom,0.001) LIMIT 1); - NEW.expl_id := (SELECT expl_id FROM exploitation WHERE ST_DWithin(NEW.the_geom, exploitation.the_geom,0.001) LIMIT 1); - + NEW.sector_id:= (SELECT sector_id FROM sector WHERE ST_DWithin(NEW.the_geom, sector.the_geom,0.001) LIMIT 1); + NEW.dma_id := (SELECT dma_id FROM dma WHERE ST_DWithin(NEW.the_geom, dma.the_geom,0.001) LIMIT 1); + NEW.expl_id := (SELECT expl_id FROM exploitation WHERE ST_DWithin(NEW.the_geom, exploitation.the_geom,0.001) LIMIT 1); + END IF; -- Reconnect arc_id @@ -707,7 +711,7 @@ BEGIN WHERE connec_id=NEW.connec_id AND psector_id = v_psector_vdefault AND cur_user = current_user AND state = 1) IS NOT NULL THEN EXECUTE 'SELECT gw_fct_linktonetwork($${"client":{"device":4, "infoType":1, "lang":"ES"}, - "feature":{"id":'|| array_to_json(array_agg(NEW.connec_id))||'},"data":{"feature_type":"CONNEC", "forceEndPoint":"true", "forcedArcs":["'||NEW.arc_id||'"]}}$$)'; + "feature":{"id":'|| array_to_json(array_agg(NEW.connec_id))||'},"data":{"feature_type":"CONNEC", "forceEndPoint":"true", "forcedArcs":["'||NEW.arc_id||'"]}}$$)'; ELSIF NEW.state = 2 THEN @@ -717,7 +721,7 @@ BEGIN WHERE connec_id=NEW.connec_id AND psector_id = v_psector_vdefault AND cur_user = current_user AND state = 1) IS NOT NULL THEN EXECUTE 'SELECT gw_fct_linktonetwork($${"client":{"device":4, "infoType":1, "lang":"ES"}, - "feature":{"id":'|| array_to_json(array_agg(NEW.connec_id))||'},"data":{"feature_type":"CONNEC", "forceEndPoint":"true", "forcedArcs":["'||NEW.arc_id||'"]}}$$)'; + "feature":{"id":'|| array_to_json(array_agg(NEW.connec_id))||'},"data":{"feature_type":"CONNEC", "forceEndPoint":"true", "forcedArcs":["'||NEW.arc_id||'"]}}$$)'; END IF; ELSE IF (SELECT link_id FROM plan_psector_x_connec JOIN selector_psector USING (psector_id) @@ -733,17 +737,17 @@ BEGIN UPDATE connec SET arc_id=NEW.arc_id where connec_id=NEW.connec_id; IF NEW.arc_id IS NOT NULL THEN - + -- when link exists IF (SELECT link_id FROM link WHERE state = 1 and feature_id = NEW.connec_id) IS NOT NULL THEN EXECUTE 'SELECT gw_fct_linktonetwork($${"client":{"device":4, "infoType":1, "lang":"ES"}, - "feature":{"id":'|| array_to_json(array_agg(NEW.connec_id))||'},"data":{"feature_type":"CONNEC", "forceEndPoint":"true", "forcedArcs":["'||NEW.arc_id||'"]}}$$)'; - END IF; + "feature":{"id":'|| array_to_json(array_agg(NEW.connec_id))||'},"data":{"feature_type":"CONNEC", "forceEndPoint":"true", "forcedArcs":["'||NEW.arc_id||'"]}}$$)'; + END IF; -- recover values in order to do not disturb this workflow SELECT * INTO v_arc FROM arc WHERE arc_id = NEW.arc_id; - NEW.pjoint_id = v_arc.arc_id; NEW.pjoint_type = 'ARC'; NEW.sector_id = v_arc.sector_id; NEW.dma_id = v_arc.dma_id; - NEW.presszone_id = v_arc.presszone_id; NEW.dqa_id = v_arc.dqa_id; NEW.minsector_id = v_arc.minsector_id; + NEW.pjoint_id = v_arc.arc_id; NEW.pjoint_type = 'ARC'; NEW.sector_id = v_arc.sector_id; NEW.dma_id = v_arc.dma_id; + NEW.presszone_id = v_arc.presszone_id; NEW.dqa_id = v_arc.dqa_id; NEW.minsector_id = v_arc.minsector_id; ELSE IF (SELECT count(*)FROM link WHERE feature_id = NEW.connec_id AND state = 1) > 0 THEN EXECUTE 'SELECT gw_fct_getmessage($${"client":{"device":4, "infoType":1, "lang":"ES"},"feature":{}, @@ -756,25 +760,25 @@ BEGIN END IF; -- Looking for state control and insert planned connecs to default psector - IF (NEW.state != OLD.state) THEN - + IF (NEW.state != OLD.state) THEN + PERFORM gw_fct_state_control('CONNEC', NEW.connec_id, NEW.state, TG_OP); - + IF NEW.state = 2 AND OLD.state=1 THEN v_link = (SELECT link_id FROM link WHERE feature_id = NEW.connec_id AND state = 1 LIMIT 1); - + INSERT INTO plan_psector_x_connec (connec_id, psector_id, state, doable, link_id, arc_id) VALUES (NEW.connec_id, v_psector_vdefault, 1, true, v_link, NEW.arc_id); - + UPDATE link SET state = 2 WHERE link_id = v_link; END IF; - + IF NEW.state = 1 AND OLD.state=2 THEN v_link = (SELECT link_id FROM link WHERE feature_id = NEW.connec_id AND state = 2 LIMIT 1); - + -- force delete UPDATE config_param_user SET value = 'true' WHERE parameter = 'plan_psector_downgrade_feature' AND cur_user= current_user; DELETE FROM plan_psector_x_connec WHERE connec_id=NEW.connec_id; @@ -784,13 +788,13 @@ BEGIN UPDATE link SET state = 1 WHERE link_id = v_link; END IF; - + UPDATE connec SET state=NEW.state WHERE connec_id = NEW.connec_id; - + END IF; - IF (NEW.connecat_id != OLD.connecat_id) AND NEW.state > 0 THEN + IF (NEW.connecat_id != OLD.connecat_id) AND NEW.state > 0 THEN UPDATE link SET connecat_id=NEW.connecat_id WHERE feature_id = NEW.connec_id AND state>0; - END IF; + END IF; -- State_type IF NEW.state=0 AND OLD.state=1 THEN @@ -816,7 +820,7 @@ BEGIN END IF; END IF; - + --check relation state - state_type IF (NEW.state_type != OLD.state_type) THEN IF NEW.state_type NOT IN (SELECT id FROM value_state_type WHERE state = NEW.state) THEN @@ -825,7 +829,7 @@ BEGIN ELSE UPDATE connec SET state_type=NEW.state_type WHERE connec_id = OLD.connec_id; END IF; - END IF; + END IF; -- rotation IF NEW.rotation != OLD.rotation THEN @@ -837,7 +841,7 @@ BEGIN IF v_link_path IS NOT NULL THEN NEW.link = replace(NEW.link, v_link_path,''); END IF; - + -- Connec type for parent tables IF v_man_table='parent' THEN IF (NEW.connecat_id != OLD.connecat_id) THEN @@ -857,14 +861,14 @@ BEGIN UPDATE connec SET customer_code=NEW.customer_code WHERE connec_id = OLD.connec_id; END IF; - UPDATE connec + UPDATE connec SET code=NEW.code, elevation=NEW.elevation, "depth"=NEW.depth, connecat_id=NEW.connecat_id, sector_id=NEW.sector_id, annotation=NEW.annotation, observ=NEW.observ, "comment"=NEW.comment, rotation=NEW.rotation,dma_id=NEW.dma_id, presszone_id=NEW.presszone_id, - soilcat_id=NEW.soilcat_id, function_type=NEW.function_type, category_type=NEW.category_type, fluid_type=NEW.fluid_type, location_type=NEW.location_type, workcat_id=NEW.workcat_id, - workcat_id_end=NEW.workcat_id_end, workcat_id_plan=NEW.workcat_id_plan, buildercat_id=NEW.buildercat_id, builtdate=NEW.builtdate, enddate=NEW.enddate, ownercat_id=NEW.ownercat_id, streetaxis2_id=v_streetaxis2, - postnumber=NEW.postnumber, postnumber2=NEW.postnumber2, muni_id=NEW.muni_id, streetaxis_id=v_streetaxis, postcode=NEW.postcode, - district_id =NEW.district_id, descript=NEW.descript, verified=NEW.verified, postcomplement=NEW.postcomplement, postcomplement2=NEW.postcomplement2, - undelete=NEW.undelete, label_x=NEW.label_x,label_y=NEW.label_y, label_rotation=NEW.label_rotation,publish=NEW.publish, + soilcat_id=NEW.soilcat_id, function_type=NEW.function_type, category_type=NEW.category_type, fluid_type=NEW.fluid_type, location_type=NEW.location_type, workcat_id=NEW.workcat_id, + workcat_id_end=NEW.workcat_id_end, workcat_id_plan=NEW.workcat_id_plan, buildercat_id=NEW.buildercat_id, builtdate=NEW.builtdate, enddate=NEW.enddate, ownercat_id=NEW.ownercat_id, streetaxis2_id=v_streetaxis2, + postnumber=NEW.postnumber, postnumber2=NEW.postnumber2, muni_id=NEW.muni_id, streetaxis_id=v_streetaxis, postcode=NEW.postcode, + district_id =NEW.district_id, descript=NEW.descript, verified=NEW.verified, postcomplement=NEW.postcomplement, postcomplement2=NEW.postcomplement2, + undelete=NEW.undelete, label_x=NEW.label_x,label_y=NEW.label_y, label_rotation=NEW.label_rotation,publish=NEW.publish, inventory=NEW.inventory, expl_id=NEW.expl_id, num_value=NEW.num_value, connec_length=NEW.connec_length, link=NEW.link, lastupdate=now(), lastupdate_user=current_user, dqa_id=NEW.dqa_id, minsector_id=NEW.minsector_id, pjoint_id=NEW.pjoint_id, pjoint_type = NEW.pjoint_type, adate=NEW.adate, adescript=NEW.adescript, accessibility = NEW.accessibility, asset_id=NEW.asset_id, epa_type = NEW.epa_type, @@ -872,26 +876,26 @@ BEGIN valve_location = NEW.valve_location, valve_type = NEW.valve_type, shutoff_valve = NEW.shutoff_valve, access_type = NEW.access_type, placement_type = NEW.placement_type, crmzone_id=NEW.crmzone_id, expl_id2=NEW.expl_id2, plot_code=NEW.plot_code, brand_id=NEW.brand_id, model_id=NEW.model_id, serial_number=NEW.serial_number, cat_valve=NEW.cat_valve WHERE connec_id=OLD.connec_id; - + IF v_man_table ='man_greentap' THEN UPDATE man_greentap SET linked_connec=NEW.linked_connec, greentap_type=NEW.greentap_type WHERE connec_id=OLD.connec_id; - + ELSIF v_man_table ='man_wjoin' THEN UPDATE man_wjoin SET top_floor=NEW.top_floor, wjoin_type=NEW.wjoin_type WHERE connec_id=OLD.connec_id; - + ELSIF v_man_table ='man_tap' THEN UPDATE man_tap SET linked_connec=NEW.linked_connec, drain_diam=NEW.drain_diam,drain_exit=NEW.drain_exit,drain_gully=NEW.drain_gully, drain_distance=NEW.drain_distance, arq_patrimony=NEW.arq_patrimony, com_state=NEW.com_state WHERE connec_id=OLD.connec_id; - - ELSIF v_man_table ='man_fountain' THEN + + ELSIF v_man_table ='man_fountain' THEN UPDATE man_fountain SET vmax=NEW.vmax,vtotal=NEW.vtotal,container_number=NEW.container_number,pump_number=NEW.pump_number,power=NEW.power, regulation_tank=NEW.regulation_tank,name=NEW.name,chlorinator=NEW.chlorinator, linked_connec=NEW.linked_connec, arq_patrimony=NEW.arq_patrimony - WHERE connec_id=OLD.connec_id; + WHERE connec_id=OLD.connec_id; END IF; -- childtable update @@ -907,15 +911,18 @@ BEGIN USING OLD INTO v_old_value_param; - IF (v_new_value_param IS NOT NULL AND v_old_value_param!=v_new_value_param) OR (v_new_value_param IS NOT NULL AND v_old_value_param IS NULL) THEN - EXECUTE 'INSERT INTO man_connec_'||lower(v_customfeature)||' (connec_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||') - ON CONFLICT (connec_id) - DO UPDATE SET '||v_addfields.param_name||'=$2::'||v_addfields.datatype_id||' WHERE man_connec_'||lower(v_customfeature)||'.connec_id=$1' - USING NEW.connec_id, v_new_value_param; - - ELSIF v_new_value_param IS NULL AND v_old_value_param IS NOT NULL THEN - EXECUTE 'UPDATE man_connec_'||lower(v_customfeature)||' SET '||v_addfields.param_name||' = null WHERE man_connec_'||lower(v_customfeature)||'.connec_id=$1' - USING NEW.connec_id; + v_childtable_name := 'man_connec' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + IF (v_new_value_param IS NOT NULL AND v_old_value_param!=v_new_value_param) OR (v_new_value_param IS NOT NULL AND v_old_value_param IS NULL) THEN + EXECUTE 'INSERT INTO '||v_childtable_name||' (connec_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||') + ON CONFLICT (connec_id) + DO UPDATE SET '||v_addfields.param_name||'=$2::'||v_addfields.datatype_id||' WHERE '||v_childtable_name||'.connec_id=$1' + USING NEW.connec_id, v_new_value_param; + + ELSIF v_new_value_param IS NULL AND v_old_value_param IS NOT NULL THEN + EXECUTE 'UPDATE '||v_childtable_name||' SET '||v_addfields.param_name||' = null WHERE '||v_childtable_name||'.connec_id=$1' + USING NEW.connec_id; + END IF; END IF; END LOOP; END IF; @@ -923,14 +930,14 @@ BEGIN RETURN NEW; ELSIF TG_OP = 'DELETE' THEN - + EXECUTE 'SELECT gw_fct_getcheckdelete($${"client":{"device":4, "infoType":1, "lang":"ES"}, "feature":{"id":"'||OLD.connec_id||'","featureType":"CONNEC"}, "data":{}}$$)'; -- force plan_psector_force_delete SELECT value INTO v_force_delete FROM config_param_user WHERE parameter = 'plan_psector_force_delete' and cur_user = current_user; UPDATE config_param_user SET value = 'true' WHERE parameter = 'plan_psector_force_delete' and cur_user = current_user; - + DELETE FROM connec WHERE connec_id = OLD.connec_id; -- restore plan_psector_force_delete @@ -947,16 +954,19 @@ BEGIN END LOOP; -- Delete childtable addfields (after or before deletion of node, doesn't matter) - + v_customfeature = old.connec_type; v_connec_id = old.connec_id; - - EXECUTE 'DELETE FROM man_connec_'||lower(v_customfeature)||' WHERE connec_id = '||quote_literal(v_connec_id)||''; + + v_childtable_name := 'man_connec' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + EXECUTE 'DELETE FROM '||v_childtable_name||' WHERE connec_id = '||quote_literal(v_connec_id)||''; + END IF; RETURN NULL; END IF; - + END; $BODY$ LANGUAGE plpgsql VOLATILE diff --git a/ws/ftrg/ws_gw_trg_edit_node.sql b/ws/ftrg/ws_gw_trg_edit_node.sql index 5bc4ff4508..32a78c33b6 100644 --- a/ws/ftrg/ws_gw_trg_edit_node.sql +++ b/ws/ftrg/ws_gw_trg_edit_node.sql @@ -66,6 +66,8 @@ v_input json; v_code_prefix text; +v_childtable_name text; + BEGIN EXECUTE 'SET search_path TO '||quote_literal(TG_TABLE_SCHEMA)||', public'; @@ -663,9 +665,12 @@ BEGIN USING NEW INTO v_new_value_param; - IF v_new_value_param IS NOT NULL THEN - EXECUTE 'INSERT INTO man_node_'||lower(v_customfeature)||' (node_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||')' - USING NEW.node_id, v_new_value_param; + v_childtable_name := 'man_node' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + IF v_new_value_param IS NOT NULL THEN + EXECUTE 'INSERT INTO '||v_childtable_name||' (node_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||')' + USING NEW.node_id, v_new_value_param; + END IF; END IF; END LOOP; END IF; @@ -1046,16 +1051,21 @@ BEGIN USING OLD INTO v_old_value_param; - IF (v_new_value_param IS NOT NULL AND v_old_value_param!=v_new_value_param) OR (v_new_value_param IS NOT NULL AND v_old_value_param IS NULL) THEN - EXECUTE 'INSERT INTO man_node_'||lower(v_customfeature)||' (node_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||') - ON CONFLICT (node_id) - DO UPDATE SET '||v_addfields.param_name||'=$2::'||v_addfields.datatype_id||' WHERE man_node_'||lower(v_customfeature)||'.node_id=$1' - USING NEW.node_id, v_new_value_param; - - ELSIF v_new_value_param IS NULL AND v_old_value_param IS NOT NULL THEN - EXECUTE 'UPDATE man_node_'||lower(v_customfeature)||' SET '||v_addfields.param_name||' = null WHERE man_node_'||lower(v_customfeature)||'.node_id=$1' - USING NEW.node_id; + v_childtable_name := 'man_node' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + IF (v_new_value_param IS NOT NULL AND v_old_value_param!=v_new_value_param) OR (v_new_value_param IS NOT NULL AND v_old_value_param IS NULL) THEN + EXECUTE 'INSERT INTO '||v_childtable_name||' (node_id, '||v_addfields.param_name||') VALUES ($1, $2::'||v_addfields.datatype_id||') + ON CONFLICT (node_id) + DO UPDATE SET '||v_addfields.param_name||'=$2::'||v_addfields.datatype_id||' WHERE '||v_childtable_name||'.node_id=$1' + USING NEW.node_id, v_new_value_param; + + ELSIF v_new_value_param IS NULL AND v_old_value_param IS NOT NULL THEN + EXECUTE 'UPDATE '||v_childtable_name||' SET '||v_addfields.param_name||' = null WHERE '||v_childtable_name||'.node_id=$1' + USING NEW.node_id; + END IF; END IF; + + END LOOP; END IF; @@ -1096,7 +1106,10 @@ BEGIN v_customfeature = old.node_type; v_node_id = old.node_id; - EXECUTE 'DELETE FROM man_node_'||lower(v_customfeature)||' WHERE node_id = '||quote_literal(v_node_id)||''; + v_childtable_name := 'man_node' || lower(v_customfeature); + IF (SELECT EXISTS ( SELECT 1 FROM information_schema.tables WHERE table_schema = TG_TABLE_SCHEMA AND table_name = v_childtable_name)) IS TRUE THEN + EXECUTE 'DELETE FROM '||v_childtable_name||' WHERE node_id = '||quote_literal(v_node_id)||''; + END IF; -- delete from node_add table