diff --git a/.docker/Dockerfile b/.docker/Dockerfile index 20c94fdf..4d505929 100644 --- a/.docker/Dockerfile +++ b/.docker/Dockerfile @@ -1,4 +1,4 @@ -ARG POSTGIS_VERSION=11-3.2 +ARG POSTGIS_VERSION=14-3.2 FROM postgis/postgis:${POSTGIS_VERSION} # System deps diff --git a/.github/workflows/docker-test-and-push.yaml b/.github/workflows/docker-test-and-push.yaml index 030ceb87..b95f75c8 100644 --- a/.github/workflows/docker-test-and-push.yaml +++ b/.github/workflows/docker-test-and-push.yaml @@ -16,25 +16,25 @@ on: jobs: docker-tests: name: Docker - runs-on: ubuntu-18.04 + runs-on: ubuntu-22.04 strategy: matrix: # postgres-postgis version, see available tags https://hub.docker.com/r/postgis/postgis/tags pgis: # WARNING: if changing this, make sure tu update `pgis_stable` below - - 9.6-3.2 - - 10-3.2 - - 11-3.2 - - 12-3.2 + - 13-3.2 + - 14-3.2 + #- 15-3.3 # Postgis 3.3 requires QGEP datamodel adaptations + # See https://github.com/QGEP/QGEP/issues/825 fail-fast: false env: # which pgis version to use for :tag images and to generate the dumps attached to the release (must be in the matrix above) - pgis_stable: "11-3.2" + pgis_stable: "14-3.2" steps: - - uses: actions/checkout@v2 + - uses: actions/checkout@v3 - name: "assert version is up to date" run: | diff --git a/02_oid_generation.sql b/02_oid_generation.sql index e0b5f476..c036d7ac 100644 --- a/02_oid_generation.sql +++ b/02_oid_generation.sql @@ -26,6 +26,7 @@ INSERT INTO qgep_sys.oid_prefixes (prefix,organization,active) VALUES ('ch17f516 INSERT INTO qgep_sys.oid_prefixes (prefix,organization,active) VALUES ('ch17nq5g','Triform',FALSE); INSERT INTO qgep_sys.oid_prefixes (prefix,organization,active) VALUES ('ch2003p6','Vevey',FALSE); INSERT INTO qgep_sys.oid_prefixes (prefix,organization,active) VALUES ('ch238z74','La Tour-de-Peilz',FALSE); +INSERT INTO qgep_sys.oid_prefixes (prefix,organization,active) VALUES ('ch234hqx','BTI',FALSE); CREATE INDEX in_qgep_is_oid_prefixes_active ON qgep_sys.oid_prefixes diff --git a/03_qgep_db_dss.sql b/03_qgep_db_dss.sql index dee16fb3..ce0e4bb9 100644 --- a/03_qgep_db_dss.sql +++ b/03_qgep_db_dss.sql @@ -33,11 +33,11 @@ CREATE TABLE qgep_sys.value_list_base ( code integer NOT NULL, vsacode integer NOT NULL, -value_en character varying(50), -value_de character varying(50), -value_fr character varying(50), -value_it character varying(60), -value_ro character varying(50), +value_en character varying(100), +value_de character varying(100), +value_fr character varying(100), +value_it character varying(100), +value_ro character varying(100), abbr_en character varying(3), abbr_de character varying(3), abbr_fr character varying(3), @@ -3538,8 +3538,8 @@ ALTER TABLE qgep_vl.water_catchment_kind ADD CONSTRAINT pkey_qgep_vl_water_catch ON UPDATE RESTRICT ON DELETE RESTRICT; ALTER TABLE qgep_od.water_catchment ADD COLUMN fk_aquifier varchar (16); ALTER TABLE qgep_od.water_catchment ADD CONSTRAINT rel_water_catchment_aquifier FOREIGN KEY (fk_aquifier) REFERENCES qgep_od.aquifier(obj_id) ON UPDATE CASCADE ON DELETE set null; -ALTER TABLE qgep_od.water_catchment ADD COLUMN fk_chute varchar (16); -ALTER TABLE qgep_od.water_catchment ADD CONSTRAINT rel_water_catchment_chute FOREIGN KEY (fk_chute) REFERENCES qgep_od.surface_water_bodies(obj_id) ON UPDATE CASCADE ON DELETE set null; +ALTER TABLE qgep_od.water_catchment ADD COLUMN fk_surface_water_bodies varchar (16); +ALTER TABLE qgep_od.water_catchment ADD CONSTRAINT rel_water_catchment_surface_water_bodies FOREIGN KEY (fk_surface_water_bodies) REFERENCES qgep_od.surface_water_bodies(obj_id) ON UPDATE CASCADE ON DELETE set null; CREATE TABLE qgep_vl.river_bank_control_grade_of_river () INHERITS (qgep_sys.value_list_base); ALTER TABLE qgep_vl.river_bank_control_grade_of_river ADD CONSTRAINT pkey_qgep_vl_river_bank_control_grade_of_river_code PRIMARY KEY (code); INSERT INTO qgep_vl.river_bank_control_grade_of_river (code, vsacode, value_en, value_de, value_fr, value_it, value_ro, abbr_en, abbr_de, abbr_fr, abbr_it, abbr_ro, active) VALUES (341,341,'none','keine','nul', 'nessuno', 'inexistent', '', '', '', '', '', 'true'); @@ -3646,8 +3646,8 @@ ALTER TABLE qgep_vl.sector_water_body_kind ADD CONSTRAINT pkey_qgep_vl_sector_wa ALTER TABLE qgep_od.sector_water_body ADD CONSTRAINT fkey_vl_sector_water_body_kind FOREIGN KEY (kind) REFERENCES qgep_vl.sector_water_body_kind (code) MATCH SIMPLE ON UPDATE RESTRICT ON DELETE RESTRICT; -ALTER TABLE qgep_od.sector_water_body ADD COLUMN fk_chute varchar (16); -ALTER TABLE qgep_od.sector_water_body ADD CONSTRAINT rel_sector_water_body_chute FOREIGN KEY (fk_chute) REFERENCES qgep_od.surface_water_bodies(obj_id) ON UPDATE CASCADE ON DELETE cascade; +ALTER TABLE qgep_od.sector_water_body ADD COLUMN fk_surface_water_bodies varchar (16); +ALTER TABLE qgep_od.sector_water_body ADD CONSTRAINT rel_sector_water_body_surface_water_bodies FOREIGN KEY (fk_surface_water_bodies) REFERENCES qgep_od.surface_water_bodies(obj_id) ON UPDATE CASCADE ON DELETE cascade; ALTER TABLE qgep_od.cooperative ADD CONSTRAINT oorel_od_cooperative_organisation FOREIGN KEY (obj_id) REFERENCES qgep_od.organisation(obj_id) ON DELETE CASCADE ON UPDATE CASCADE; ALTER TABLE qgep_od.canton ADD CONSTRAINT oorel_od_canton_organisation FOREIGN KEY (obj_id) REFERENCES qgep_od.organisation(obj_id) ON DELETE CASCADE ON UPDATE CASCADE; ALTER TABLE qgep_od.waste_water_association ADD CONSTRAINT oorel_od_waste_water_association_organisation FOREIGN KEY (obj_id) REFERENCES qgep_od.organisation(obj_id) ON DELETE CASCADE ON UPDATE CASCADE; @@ -4202,8 +4202,8 @@ ALTER TABLE qgep_vl.rock_ramp_stabilisation ADD CONSTRAINT pkey_qgep_vl_rock_ram ON UPDATE RESTRICT ON DELETE RESTRICT; ALTER TABLE qgep_od.fish_pass ADD COLUMN fk_water_control_structure varchar (16); ALTER TABLE qgep_od.fish_pass ADD CONSTRAINT rel_fish_pass_water_control_structure FOREIGN KEY (fk_water_control_structure) REFERENCES qgep_od.water_control_structure(obj_id) ON UPDATE CASCADE ON DELETE cascade; -ALTER TABLE qgep_od.bathing_area ADD COLUMN fk_chute varchar (16); -ALTER TABLE qgep_od.bathing_area ADD CONSTRAINT rel_bathing_area_chute FOREIGN KEY (fk_chute) REFERENCES qgep_od.surface_water_bodies(obj_id) ON UPDATE CASCADE ON DELETE set null; +ALTER TABLE qgep_od.bathing_area ADD COLUMN fk_surface_water_bodies varchar (16); +ALTER TABLE qgep_od.bathing_area ADD CONSTRAINT rel_bathing_area_surface_water_bodies FOREIGN KEY (fk_surface_water_bodies) REFERENCES qgep_od.surface_water_bodies(obj_id) ON UPDATE CASCADE ON DELETE set null; ALTER TABLE qgep_od.wastewater_networkelement ADD COLUMN fk_wastewater_structure varchar (16); ALTER TABLE qgep_od.wastewater_networkelement ADD CONSTRAINT rel_wastewater_networkelement_wastewater_structure FOREIGN KEY (fk_wastewater_structure) REFERENCES qgep_od.wastewater_structure(obj_id) ON UPDATE CASCADE ON DELETE cascade; CREATE TABLE qgep_vl.reach_point_elevation_accuracy () INHERITS (qgep_sys.value_list_base); diff --git a/05_data_model_extensions.sql b/05_data_model_extensions.sql index e1e07e17..d3659049 100644 --- a/05_data_model_extensions.sql +++ b/05_data_model_extensions.sql @@ -36,20 +36,26 @@ added solely for QGEP'; -- this column is an extension to the VSA data model and puts the _function_hierarchic in order ALTER TABLE qgep_vl.channel_function_hierarchic ADD COLUMN order_fct_hierarchic smallint; -UPDATE qgep_vl.channel_function_hierarchic SET order_fct_hierarchic=5 WHERE code=5062; -UPDATE qgep_vl.channel_function_hierarchic SET order_fct_hierarchic=7 WHERE code=5063; -UPDATE qgep_vl.channel_function_hierarchic SET order_fct_hierarchic=6 WHERE code=5064; -UPDATE qgep_vl.channel_function_hierarchic SET order_fct_hierarchic=8 WHERE code=5065; -UPDATE qgep_vl.channel_function_hierarchic SET order_fct_hierarchic=10 WHERE code=5066; -UPDATE qgep_vl.channel_function_hierarchic SET order_fct_hierarchic=13 WHERE code=5067; -UPDATE qgep_vl.channel_function_hierarchic SET order_fct_hierarchic=1 WHERE code=5068; -UPDATE qgep_vl.channel_function_hierarchic SET order_fct_hierarchic=3 WHERE code=5069; -UPDATE qgep_vl.channel_function_hierarchic SET order_fct_hierarchic=2 WHERE code=5070; -UPDATE qgep_vl.channel_function_hierarchic SET order_fct_hierarchic=4 WHERE code=5071; -UPDATE qgep_vl.channel_function_hierarchic SET order_fct_hierarchic=9 WHERE code=5072; -UPDATE qgep_vl.channel_function_hierarchic SET order_fct_hierarchic=12 WHERE code=5073; -UPDATE qgep_vl.channel_function_hierarchic SET order_fct_hierarchic=11 WHERE code=5074; -UPDATE qgep_vl.channel_function_hierarchic SET order_fct_hierarchic=14 WHERE code=5075; +UPDATE qgep_vl.channel_function_hierarchic +SET order_fct_hierarchic= + array_position( + ARRAY[ + 5068 --pwwf.water_bodies + ,5070 --pwwf.main_drain_regional + ,5069 --pwwf.main_drain + ,5071 --pwwf.collector_sewer + ,5062 --pwwf.renovation_conduction + ,5064 --pwwf.residential_drainage + ,5072 --pwwf.road_drainage + ,5066 --pwwf.other + ,5074 --pwwf.unknown + ,5063 --swwf.renovation_conduction + ,5065 --swwf.residential_drainage + ,5073 --swwf.road_drainage + ,5067 --swwf.other + ,5075 --swwf.unknown + ] + ,code) ; -- this column is an extension to the VSA data model and puts the _usage_current in order ALTER TABLE qgep_vl.channel_usage_current ADD COLUMN order_usage_current smallint; diff --git a/delta/delta_1.5.8_tbl_swmm_coefficient_friction.sql b/delta/delta_1.5.8_tbl_swmm_coefficient_friction.sql index 33a89ec6..a9b97cfb 100644 --- a/delta/delta_1.5.8_tbl_swmm_coefficient_friction.sql +++ b/delta/delta_1.5.8_tbl_swmm_coefficient_friction.sql @@ -4,7 +4,7 @@ ALTER TABLE qgep_swmm.reach_coefficient_of_friction ADD CONSTRAINT pkey_qgep_vl_reach_coefficient_of_friction_id PRIMARY KEY (fk_material); INSERT INTO qgep_swmm.reach_coefficient_of_friction(fk_material) - SELECT vsacode + SELECT DISTINCT vsacode FROM qgep_vl.reach_material; UPDATE qgep_swmm.reach_coefficient_of_friction diff --git a/delta/delta_1.6.1_add_ii_to_swmm_outfalls b/delta/delta_1.6.1_add_ii_to_swmm_outfalls new file mode 100644 index 00000000..16199ac9 --- /dev/null +++ b/delta/delta_1.6.1_add_ii_to_swmm_outfalls @@ -0,0 +1,4 @@ +-------- +-- View for the swmm module class outfalls now includes infiltration installations +-------- +SELECT 1; diff --git a/delta/delta_1.6.1_allow_longer_vl_names.sql b/delta/delta_1.6.1_allow_longer_vl_names.sql new file mode 100644 index 00000000..8c0114da --- /dev/null +++ b/delta/delta_1.6.1_allow_longer_vl_names.sql @@ -0,0 +1,10 @@ +ALTER TABLE qgep_sys.value_list_base +ALTER COLUMN value_en TYPE character varying(100); +ALTER TABLE qgep_sys.value_list_base +ALTER COLUMN value_de TYPE character varying(100); +ALTER TABLE qgep_sys.value_list_base +ALTER COLUMN value_fr TYPE character varying(100); +ALTER TABLE qgep_sys.value_list_base +ALTER COLUMN value_it TYPE character varying(100); +ALTER TABLE qgep_sys.value_list_base +ALTER COLUMN value_ro TYPE character varying(100); diff --git a/delta/delta_1.6.1_alter_order_fct_hierarchic.sql b/delta/delta_1.6.1_alter_order_fct_hierarchic.sql new file mode 100644 index 00000000..0760b89f --- /dev/null +++ b/delta/delta_1.6.1_alter_order_fct_hierarchic.sql @@ -0,0 +1,20 @@ +UPDATE qgep_vl.channel_function_hierarchic +SET order_fct_hierarchic= + array_position( + ARRAY[ + 5068 --pwwf.water_bodies + ,5070 --pwwf.main_drain_regional + ,5069 --pwwf.main_drain + ,5071 --pwwf.collector_sewer + ,5062 --pwwf.renovation_conduction + ,5064 --pwwf.residential_drainage + ,5072 --pwwf.road_drainage + ,5066 --pwwf.other + ,5074 --pwwf.unknown + ,5063 --swwf.renovation_conduction + ,5065 --swwf.residential_drainage + ,5073 --swwf.road_drainage + ,5067 --swwf.other + ,5075 --swwf.unknown + ] + ,code) diff --git a/delta/delta_1.6.1_dss_rename_xxx_fk_chute_to_fk_surface_water_bodies.sql b/delta/delta_1.6.1_dss_rename_xxx_fk_chute_to_fk_surface_water_bodies.sql new file mode 100644 index 00000000..50fa8d06 --- /dev/null +++ b/delta/delta_1.6.1_dss_rename_xxx_fk_chute_to_fk_surface_water_bodies.sql @@ -0,0 +1,69 @@ +-- class water_catchment +--1. add correct fk_surface_water_bodies +ALTER TABLE IF EXISTS qgep_od.water_catchment ADD COLUMN fk_surface_water_bodies varchar (16); + +-- 2. add correct CONSTRAINT +-- ALTER TABLE qgep_od.water_catchment ADD CONSTRAINT rel_water_catchment_chute FOREIGN KEY (fk_chute) REFERENCES qgep_od.surface_water_bodies(obj_id) ON UPDATE CASCADE ON DELETE set null; + +ALTER TABLE IF EXISTS qgep_od.water_catchment ADD CONSTRAINT rel_water_catchment_surface_water_bodies FOREIGN KEY (fk_surface_water_bodies) REFERENCES qgep_od.surface_water_bodies(obj_id) ON UPDATE CASCADE ON DELETE set null; + +--3. copy data from fk_chute to fk_surface_water_bodies +UPDATE qgep_od.water_catchment +SET fk_surface_water_bodies = fk_chute; + +-- 4. delete old rel_water_catchment_chute constraint +ALTER TABLE IF EXISTS qgep_od.water_catchment DROP CONSTRAINT rel_water_catchment_chute; + +-- 5. delete wrong fk_chute column +ALTER TABLE IF EXISTS qgep_od.water_catchment DROP COLUMN fk_chute; + +-- 6. rename wrong value in qgep_sys.dictionary_od_field +-- not needed as fk_attributes are not in qgep_sys tables + + +-- class bathing_area +--1. add correct fk_surface_water_bodies +ALTER TABLE IF EXISTS qgep_od.bathing_area ADD COLUMN fk_surface_water_bodies varchar (16); + +-- 2. add correct CONSTRAINT +-- ALTER TABLE qgep_od.bathing_area ADD CONSTRAINT rel_bathing_area_chute FOREIGN KEY (fk_chute) REFERENCES qgep_od.surface_water_bodies(obj_id) ON UPDATE CASCADE ON DELETE set null; + +ALTER TABLE IF EXISTS qgep_od.bathing_area ADD CONSTRAINT rel_bathing_area_surface_water_bodies FOREIGN KEY (fk_surface_water_bodies) REFERENCES qgep_od.surface_water_bodies(obj_id) ON UPDATE CASCADE ON DELETE set null; + +--3. copy data from fk_chute to fk_surface_water_bodies +UPDATE qgep_od.bathing_area +SET fk_surface_water_bodies = fk_chute; + +-- 4. delete old rel_water_catchment_chute constraint +ALTER TABLE IF EXISTS qgep_od.bathing_area DROP CONSTRAINT rel_bathing_area_chute; + +-- 5. delete wrong fk_chute column +ALTER TABLE IF EXISTS qgep_od.bathing_area DROP COLUMN fk_chute; + +-- 6. rename wrong value in qgep_sys.dictionary_od_field +-- not needed as fk_attributes are not in qgep_sys tables + + + +-- class sector_water_body +--1. add correct fk_surface_water_bodies +ALTER TABLE IF EXISTS qgep_od.sector_water_body ADD COLUMN fk_surface_water_bodies varchar (16); + +-- 2. add correct CONSTRAINT +-- ALTER TABLE qgep_od.sector_water_body ADD CONSTRAINT rel_sector_water_body_chute FOREIGN KEY (fk_chute) REFERENCES qgep_od.surface_water_bodies(obj_id) ON UPDATE CASCADE ON DELETE set null; + +ALTER TABLE IF EXISTS qgep_od.sector_water_body ADD CONSTRAINT rel_sector_water_body_surface_water_bodies FOREIGN KEY (fk_surface_water_bodies) REFERENCES qgep_od.surface_water_bodies(obj_id) ON UPDATE CASCADE ON DELETE set null; + +--3. copy data from fk_chute to fk_surface_water_bodies +UPDATE qgep_od.sector_water_body +SET fk_surface_water_bodies = fk_chute; + +-- 4. delete old rel_water_catchment_chute constraint +ALTER TABLE IF EXISTS qgep_od.sector_water_body DROP CONSTRAINT rel_sector_water_body_chute; + +-- 5. delete wrong fk_chute column +ALTER TABLE IF EXISTS qgep_od.sector_water_body DROP COLUMN fk_chute; + +-- 6. rename wrong value in qgep_sys.dictionary_od_field +-- not needed as fk_attributes are not in qgep_sys tables + diff --git a/swmm_views/02_vw_swmm_junctions.sql b/swmm_views/02_vw_swmm_junctions.sql index 992be3a3..1b079fac 100644 --- a/swmm_views/02_vw_swmm_junctions.sql +++ b/swmm_views/02_vw_swmm_junctions.sql @@ -15,11 +15,11 @@ SELECT CONCAT_WS(',', 'manhole', mf.value_en) as tag, wn.situation_geometry as geom, CASE - WHEN status IN (7959, 6529, 6526) THEN 'planned' + WHEN ws_st.vsacode IN (7959, 6529, 6526) THEN 'planned' ELSE 'current' END as state, CASE - WHEN ws._function_hierarchic in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' + WHEN ch_fh.vsacode in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' ELSE 'secondary' END as hierarchy, wn.obj_id as obj_id @@ -29,8 +29,10 @@ LEFT JOIN qgep_od.wastewater_networkelement we ON we.fk_wastewater_structure::te LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = we.obj_id LEFT JOIN qgep_od.cover co on ws.fk_main_cover = co.obj_id LEFT JOIN qgep_vl.manhole_function mf on ma.function = mf.code +LEFT JOIN qgep_vl.wastewater_structure_status ws_st on ws_st.code=ws.status +LEFT JOIN qgep_vl.channel_function_hierarchic ch_fh on ch_fh.code=ws._function_hierarchic WHERE wn.obj_id IS NOT NULL -AND status IN (6530, 6533, 8493, 6529, 6526, 7959) +AND ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959) UNION @@ -43,14 +45,14 @@ SELECT NULL::float as SurchargeDepth, NULL::float as PondedArea, ws.identifier::text as description, - CONCAT_WS(',','special_structure', ssf.value_en) as tag, + CONCAT_WS(',','special_structure', ss_fu.value_en) as tag, wn.situation_geometry as geom, CASE - WHEN status IN (7959, 6529, 6526) THEN 'planned' + WHEN ws_st.vsacode IN (7959, 6529, 6526) THEN 'planned' ELSE 'current' END as state, CASE - WHEN ws._function_hierarchic in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' + WHEN ch_fh.vsacode in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' ELSE 'secondary' END as hierarchy, wn.obj_id as obj_id @@ -59,10 +61,12 @@ LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id::text = ss.obj_id::text LEFT JOIN qgep_od.wastewater_networkelement we ON we.fk_wastewater_structure::text = ws.obj_id::text LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = we.obj_id LEFT JOIN qgep_od.cover co on ws.fk_main_cover = co.obj_id -LEFT JOIN qgep_vl.special_structure_function ssf on ss.function = ssf.code +LEFT JOIN qgep_vl.special_structure_function ss_fu on ss_fu.code=ss.function +LEFT JOIN qgep_vl.wastewater_structure_status ws_st on ws_st.code=ws.status +LEFT JOIN qgep_vl.channel_function_hierarchic ch_fh on ch_fh.code=ws._function_hierarchic WHERE wn.obj_id IS NOT NULL -AND status IN (6530, 6533, 8493, 6529, 6526, 7959) -AND function NOT IN ( -- must be the same list in vw_swmm_storages +AND ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959) +AND ss_fu.vsacode NOT IN ( -- must be the same list in vw_swmm_storages 6397, --"pit_without_drain" -- 245, --"drop_structure" 6398, --"hydrolizing_tank" @@ -109,11 +113,11 @@ SELECT 'junction without structure' as tag, coalesce(from_wn.situation_geometry, ST_StartPoint(re.progression_geometry)) as geom, CASE - WHEN ws.status IN (7959, 6529, 6526) THEN 'planned' + WHEN ws_st.vsacode IN (7959, 6529, 6526) THEN 'planned' ELSE 'current' END as state, CASE - WHEN ch.function_hierarchic in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' + WHEN ch_fh.vsacode in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' ELSE 'secondary' END as hierarchy, coalesce(from_wn.obj_id, re.obj_id) as obj_id @@ -126,8 +130,10 @@ LEFT JOIN qgep_od.channel ch on ch.obj_id::text = ws.obj_id::text -- Get wastewater structure linked to the from node LEFT JOIN qgep_od.wastewater_networkelement we ON from_wn.obj_id = we.obj_id LEFT JOIN qgep_od.wastewater_structure ws_node ON we.fk_wastewater_structure::text = ws_node.obj_id::text +LEFT JOIN qgep_vl.wastewater_structure_status ws_st on ws_st.code=ws.status +LEFT JOIN qgep_vl.channel_function_hierarchic ch_fh on ch_fh.code=ch.function_hierarchic -- select only operationals and "planned" -WHERE ws.status IN (6530, 6533, 8493, 6529, 6526, 7959) +WHERE ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959) and ws_node is null UNION @@ -143,11 +149,11 @@ SELECT 'junction without structure' as tag, coalesce(to_wn.situation_geometry, ST_EndPoint(re.progression_geometry)) as geom, CASE - WHEN ws.status IN (7959, 6529, 6526) THEN 'planned' + WHEN ws_st.vsacode IN (7959, 6529, 6526) THEN 'planned' ELSE 'current' END as state, CASE - WHEN ch.function_hierarchic in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' + WHEN ch_fh.vsacode in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' ELSE 'secondary' END as hierarchy, coalesce(to_wn.obj_id, re.obj_id) as obj_id @@ -160,6 +166,8 @@ LEFT JOIN qgep_od.channel ch on ch.obj_id::text = ws.obj_id::text -- Get wastewater structure linked to the to node LEFT JOIN qgep_od.wastewater_networkelement we ON to_wn.obj_id = we.obj_id LEFT JOIN qgep_od.wastewater_structure ws_node ON we.fk_wastewater_structure::text = ws_node.obj_id::text +LEFT JOIN qgep_vl.wastewater_structure_status ws_st on ws_st.code=ws.status +LEFT JOIN qgep_vl.channel_function_hierarchic ch_fh on ch_fh.code=ch.function_hierarchic -- select only operationals and "planned" -WHERE ws.status IN (6530, 6533, 8493, 6529, 6526, 7959) +WHERE ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959) and ws_node is null; diff --git a/swmm_views/04_vw_swmm_conduits.sql b/swmm_views/04_vw_swmm_conduits.sql index e031e16c..c82a89e9 100644 --- a/swmm_views/04_vw_swmm_conduits.sql +++ b/swmm_views/04_vw_swmm_conduits.sql @@ -19,7 +19,7 @@ SELECT WHEN re.coefficient_of_friction IS NOT NULL THEN (1 / re.coefficient_of_friction::double precision) WHEN re.coefficient_of_friction IS NULL AND re.wall_roughness IS NOT NULL THEN CASE - WHEN re.clear_height IS NOT NULL THEN (1 / (4 * SQRT(9.81) * POWER((32 / re.clear_height::double precision / 1000),(1 / 6::double precision))*LOG(((3.71 * re.clear_height::double precision / 1000) / (re.wall_roughness / 1000)))))::numeric(7,4) + WHEN re.clear_height IS NOT NULL THEN 1./((4. * SQRT(9.81) * POWER((32. / (re.clear_height::double precision / 1000.)),(1. / 6.::double precision)))*LOG(((3.71 * (re.clear_height::double precision / 1000.)) / (re.wall_roughness / 1000.))))::numeric(7,4) WHEN re.clear_height IS NULL AND re.swmm_default_coefficient_of_friction IS NOT NULL THEN (1 / re.swmm_default_coefficient_of_friction::double precision) ELSE 0.01 END @@ -37,10 +37,10 @@ SELECT concat_ws(';', ws.identifier, CASE - WHEN re.coefficient_of_friction IS NOT NULL THEN '1 / K_Strickler is used as roughness' + WHEN re.coefficient_of_friction IS NOT NULL THEN '1 / K_Strickler, 1/re.coefficient_of_friction is used as roughness' WHEN re.coefficient_of_friction IS NULL AND re.wall_roughness IS NOT NULL THEN CASE - WHEN re.clear_height IS NOT NULL THEN 'The approximation of 1 / K_Strickler is computed using K_Colebrook to determined the roughness as roughness' + WHEN re.clear_height IS NOT NULL THEN 'The approximation of 1 / K_Strickler is computed from re.wall_roughness using an approximation formula.' WHEN re.clear_height IS NULL AND re.swmm_default_coefficient_of_friction IS NOT NULL THEN 'The default value stored in reach.swmm_default_coefficient_of_friction is used' ELSE 'Default value 0.01 is used as roughness' END @@ -52,17 +52,17 @@ SELECT ELSE 'Default value 0.01 is used as roughness' END, CASE - WHEN pp.profile_type = 3350 THEN + WHEN vl_pp.vsacode = 3350 THEN CASE WHEN re.clear_height = 0 OR re.clear_height IS NULL THEN concat('Reach', re.obj_id,': circular profile with default value of 0.1m as clear_height') ELSE NULL END - WHEN pp.profile_type = 3351 THEN + WHEN vl_pp.vsacode = 3351 THEN CASE WHEN re.clear_height = 0 OR re.clear_height IS NULL THEN concat('Reach', re.obj_id,': egg profile with default value of 0.1m as clear_height') ELSE NULL END - WHEN pp.profile_type = 3352 THEN + WHEN vl_pp.vsacode = 3352 THEN CASE WHEN pp.height_width_ratio IS NOT NULL THEN CASE @@ -75,7 +75,7 @@ SELECT ELSE concat('Reach', re.obj_id,': arch profile with default value of 1 as height_width_ratio and with known clear_height value') END END - WHEN pp.profile_type = 3353 THEN + WHEN vl_pp.vsacode = 3353 THEN CASE WHEN pp.height_width_ratio IS NOT NULL THEN CASE @@ -88,7 +88,7 @@ SELECT ELSE concat('Reach', re.obj_id,': rectangular profile with default value of 1 as height_width_ratio and with known clear_height value') END END - WHEN pp.profile_type = 3354 THEN + WHEN vl_pp.vsacode = 3354 THEN CASE WHEN pp.height_width_ratio IS NOT NULL THEN CASE @@ -101,7 +101,7 @@ SELECT ELSE concat('Reach', re.obj_id,': parabolic profile with default value of 1 as height_width_ratio, with known clear_height value and no code value') END END - WHEN pp.profile_type = 3355 THEN concat('Reach', re.obj_id,': custom profile to be defined in SWMM') + WHEN vl_pp.vsacode = 3355 THEN concat('Reach', re.obj_id,': custom profile to be defined in SWMM') END, CASE WHEN to_wn.obj_id IS NULL THEN 'Blind connection, the destination node must be edited' @@ -109,19 +109,20 @@ SELECT ELSE NULL END ) as description, - cfh.value_en as tag, + cfhy.value_en as tag, ST_CurveToLine(st_force3d(progression_geometry))::geometry(LineStringZ, %(SRID)s) as geom, CASE WHEN status IN (7959, 6529, 6526) THEN 'planned' ELSE 'current' END as state, CASE - WHEN ch.function_hierarchic in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' + WHEN cfhi.vsacode in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' ELSE 'secondary' END as hierarchy, re.obj_id as obj_id FROM qgep_od.reach as re LEFT JOIN qgep_od.pipe_profile pp on pp.obj_id = re.fk_pipe_profile +LEFT JOIN qgep_vl.pipe_profile_profile_type vl_pp on pp.profile_type = vl_pp.code LEFT JOIN qgep_od.wastewater_networkelement ne ON ne.obj_id::text = re.obj_id::text LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure LEFT JOIN qgep_od.reach_point rp_from ON rp_from.obj_id::text = re.fk_reach_point_from::text @@ -129,7 +130,8 @@ LEFT JOIN qgep_od.reach_point rp_to ON rp_to.obj_id::text = re.fk_reach_point_to LEFT JOIN qgep_od.wastewater_node from_wn on from_wn.obj_id = rp_from.fk_wastewater_networkelement LEFT JOIN qgep_od.wastewater_node to_wn on to_wn.obj_id = rp_to.fk_wastewater_networkelement LEFT JOIN qgep_od.channel ch on ch.obj_id::text = ws.obj_id::text -LEFT JOIN qgep_vl.channel_function_hydraulic cfh on cfh.code = ch.function_hydraulic +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi on cfhi.code = ch.function_hierarchic +LEFT JOIN qgep_vl.channel_function_hydraulic cfhy on cfhy.code = ch.function_hydraulic -- select only operationals and "planned" WHERE status IN (6530, 6533, 8493, 6529, 6526, 7959); -- 6526 "other.calculation_alternative" diff --git a/swmm_views/05_vw_swmm_dividers.sql b/swmm_views/05_vw_swmm_dividers.sql index dfeecbe0..310bb178 100644 --- a/swmm_views/05_vw_swmm_dividers.sql +++ b/swmm_views/05_vw_swmm_dividers.sql @@ -15,22 +15,24 @@ SELECT 0 as PondedArea, wn.situation_geometry as geom, CASE - WHEN status IN (7959, 6529, 6526) THEN 'planned' + WHEN ws_st.vsacode IN (7959, 6529, 6526) THEN 'planned' ELSE 'current' END as state, CASE - WHEN ws._function_hierarchic in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' + WHEN cfhi.vsacode in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' ELSE 'secondary' END as hierarchy, wn.obj_id as obj_id FROM qgep_od.manhole ma LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id::text = ma.obj_id::text +LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic LEFT JOIN qgep_od.wastewater_networkelement ne ON ne.fk_wastewater_structure::text = ws.obj_id::text LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id LEFT JOIN qgep_od.cover co on ws.fk_main_cover = co.obj_id LEFT JOIN qgep_vl.manhole_function mf on ma.function = mf.code -WHERE function = 4798 -- separating_structure -AND status IN (6530, 6533, 8493, 6529, 6526, 7959) +WHERE mf.vsacode = 4798 -- separating_structure +AND ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959) UNION ALL @@ -46,19 +48,21 @@ SELECT 0 as PondedArea, wn.situation_geometry as geom, CASE - WHEN status IN (7959, 6529, 6526) THEN 'planned' + WHEN ws_st.vsacode IN (7959, 6529, 6526) THEN 'planned' ELSE 'current' END as state, CASE - WHEN ws._function_hierarchic in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' + WHEN cfhi.vsacode in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' ELSE 'secondary' END as hierarchy, wn.obj_id as obj_id FROM qgep_od.special_structure ss LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id::text = ss.obj_id::text +LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic LEFT JOIN qgep_od.wastewater_networkelement ne ON ne.fk_wastewater_structure::text = ws.obj_id::text LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id LEFT JOIN qgep_od.cover co on ws.fk_main_cover = co.obj_id LEFT JOIN qgep_vl.special_structure_function ssf on ss.function = ssf.code -WHERE function = 4799 -- separating_structure -AND status IN (6530, 6533, 8493, 6529, 6526, 7959); +WHERE ssf.vsacode = 4799 -- separating_structure +AND ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959); diff --git a/swmm_views/07_vw_swmm_losses.sql b/swmm_views/07_vw_swmm_losses.sql index 07826969..e10079a0 100644 --- a/swmm_views/07_vw_swmm_losses.sql +++ b/swmm_views/07_vw_swmm_losses.sql @@ -30,5 +30,6 @@ LEFT JOIN qgep_od.reach_point rp_from ON rp_from.obj_id::text = re.fk_reach_poin LEFT JOIN qgep_od.wastewater_node from_wn on from_wn.obj_id = rp_from.fk_wastewater_networkelement LEFT JOIN qgep_od.throttle_shut_off_unit ts ON ts.fk_wastewater_node = from_wn.obj_id LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure -WHERE status IN (6530, 6533, 8493, 6529, 6526, 7959) +LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code +WHERE ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959) ; -- wastewater node of the downstream wastewater node diff --git a/swmm_views/08_vw_swmm_outfalls.sql b/swmm_views/08_vw_swmm_outfalls.sql index 9861eb63..b0dc5feb 100644 --- a/swmm_views/08_vw_swmm_outfalls.sql +++ b/swmm_views/08_vw_swmm_outfalls.sql @@ -14,18 +14,50 @@ SELECT dp.obj_id::varchar as tag, wn.situation_geometry as geom, CASE - WHEN status IN (7959, 6529, 6526) THEN 'planned' + WHEN ws_st.vsacode IN (7959, 6529, 6526) THEN 'planned' ELSE 'current' END as state, CASE - WHEN ws._function_hierarchic in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' + WHEN cfhi.vsacode in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' ELSE 'secondary' END as hierarchy, wn.obj_id as obj_id FROM qgep_od.discharge_point as dp LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id::text = dp.obj_id::text +LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic LEFT JOIN qgep_od.wastewater_networkelement we ON we.fk_wastewater_structure::text = ws.obj_id::text LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = we.obj_id WHERE wn.obj_id IS NOT NULL -AND status IN (6530, 6533, 8493, 6529, 6526, 7959) +AND ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959) + +UNION + +SELECT + wn.obj_id as Name, + coalesce(wn.bottom_level,0) as InvertElev, + 'FREE'::varchar as Type, + NULL as StageData, + 'NO'::varchar as tide_gate, + NULL::varchar as RouteTo, + ws.identifier as description, + ii.obj_id::varchar as tag, + wn.situation_geometry as geom, + CASE + WHEN ws_st.vsacode IN (7959, 6529, 6526) THEN 'planned' + ELSE 'current' + END as state, + CASE + WHEN cfhi.vsacode in (5062, 5064, 5066, 5068, 5069, 5070, 5071, 5072, 5074) THEN 'primary' + ELSE 'secondary' + END as hierarchy, + wn.obj_id as obj_id +FROM qgep_od.infiltration_installation as ii +LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id::text = ii.obj_id::text +LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic +LEFT JOIN qgep_od.wastewater_networkelement we ON we.fk_wastewater_structure::text = ws.obj_id::text +LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = we.obj_id +WHERE wn.obj_id IS NOT NULL +AND ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959) ; diff --git a/swmm_views/09_vw_swmm_subcatchments.sql b/swmm_views/09_vw_swmm_subcatchments.sql index 41b04bb2..56d367c3 100644 --- a/swmm_views/09_vw_swmm_subcatchments.sql +++ b/swmm_views/09_vw_swmm_subcatchments.sql @@ -81,27 +81,69 @@ SELECT END as hierarchy, wn_obj_id as obj_id FROM ( - SELECT ca.*, wn.situation_geometry as wn_geom, 'rw_current' as state, wn.obj_id as wn_obj_id, ws._function_hierarchic - FROM qgep_od.catchment_area as ca - INNER JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = ca.fk_wastewater_networkelement_rw_current - LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id - LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure - UNION ALL - SELECT ca.*, wn.situation_geometry as wn_geom, 'rw_planned' as state, wn.obj_id as wn_obj_id, ws._function_hierarchic - FROM qgep_od.catchment_area as ca - INNER JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = ca.fk_wastewater_networkelement_rw_planned - LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id - LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure - UNION ALL - SELECT ca.*, wn.situation_geometry as wn_geom, 'ww_current' as state, wn.obj_id as wn_obj_id, ws._function_hierarchic - FROM qgep_od.catchment_area as ca - INNER JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = ca.fk_wastewater_networkelement_ww_current - LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id - LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure - UNION ALL - SELECT ca.*, wn.situation_geometry as wn_geom,'ww_planned' as state, wn.obj_id as wn_obj_id, ws._function_hierarchic - FROM qgep_od.catchment_area as ca - INNER JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = ca.fk_wastewater_networkelement_ww_planned - LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id - LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure + SELECT ca_1.obj_id, + ddc.vsacode as direct_discharge_current, + ddp.vsacode as direct_discharge_planned, + ca_1.discharge_coefficient_rw_current, + ca_1.discharge_coefficient_rw_planned, + ca_1.discharge_coefficient_ww_current, + ca_1.discharge_coefficient_ww_planned, + dsc.vsacode as drainage_system_current, + dsp.vsacode as drainage_system_planned, + ca_1.identifier, + ic.vsacode as infiltration_current, + ip.vsacode as infiltration_planned, + ca_1.perimeter_geometry, + ca_1.population_density_current, + ca_1.population_density_planned, + ca_1.remark, + rc.vsacode as retention_current, + rp.vsacode as retention_planned, + ca_1.runoff_limit_current, + ca_1.runoff_limit_planned, + ca_1.seal_factor_rw_current, + ca_1.seal_factor_rw_planned, + ca_1.seal_factor_ww_current, + ca_1.seal_factor_ww_planned, + ca_1.sewer_infiltration_water_production_current, + ca_1.sewer_infiltration_water_production_planned, + ca_1.surface_area, + ca_1.waste_water_production_current, + ca_1.waste_water_production_planned, + ca_1.last_modification, + ca_1.fk_dataowner, + ca_1.fk_provider, + ca_1.fk_wastewater_networkelement_rw_current, + ca_1.fk_wastewater_networkelement_rw_planned, + ca_1.fk_wastewater_networkelement_ww_planned, + ca_1.fk_wastewater_networkelement_ww_current, + wn.situation_geometry AS wn_geom, + CASE WHEN ca_1.fk_wastewater_networkelement_rw_current =wn.obj_id + THEN 'rw_current'::text + WHEN ca_1.fk_wastewater_networkelement_ww_current =wn.obj_id + THEN 'ww_current'::text + WHEN ca_1.fk_wastewater_networkelement_rw_planned =wn.obj_id + THEN 'rw_planned'::text + WHEN ca_1.fk_wastewater_networkelement_ww_planned =wn.obj_id + THEN 'ww_planned'::text + ELSE 'ERROR' + END AS state, + wn.obj_id AS wn_obj_id, + fhy.vsacode as _function_hierarchic + FROM qgep_od.catchment_area ca_1 + JOIN qgep_od.wastewater_networkelement ne + ON ne.obj_id::text IN (ca_1.fk_wastewater_networkelement_rw_current::text, + ca_1.fk_wastewater_networkelement_ww_current::text, + ca_1.fk_wastewater_networkelement_rw_planned::text, + ca_1.fk_wastewater_networkelement_ww_planned::text) + LEFT JOIN qgep_od.wastewater_node wn ON wn.obj_id::text = ne.obj_id::text + LEFT JOIN qgep_vl.catchment_area_direct_discharge_current ddc ON ddc.code=ca_1.direct_discharge_current + LEFT JOIN qgep_vl.catchment_area_direct_discharge_planned ddp ON ddp.code=ca_1.direct_discharge_planned + LEFT JOIN qgep_vl.catchment_area_drainage_system_current dsc ON dsc.code=ca_1.drainage_system_current + LEFT JOIN qgep_vl.catchment_area_drainage_system_planned dsp ON dsp.code=ca_1.drainage_system_planned + LEFT JOIN qgep_vl.catchment_area_infiltration_current ic ON ic.code=ca_1.infiltration_current + LEFT JOIN qgep_vl.catchment_area_infiltration_planned ip ON ip.code=ca_1.infiltration_planned + LEFT JOIN qgep_vl.catchment_area_retention_current rc ON rc.code=ca_1.retention_current + LEFT JOIN qgep_vl.catchment_area_retention_planned rp ON rp.code=ca_1.retention_planned + LEFT JOIN qgep_vl.channel_function_hierarchic fhy ON fhy.code=wn._function_hierarchic ) as ca; diff --git a/swmm_views/10_vw_swmm_subareas.sql b/swmm_views/10_vw_swmm_subareas.sql index f7b0fbd6..c7b09376 100644 --- a/swmm_views/10_vw_swmm_subareas.sql +++ b/swmm_views/10_vw_swmm_subareas.sql @@ -25,35 +25,39 @@ SELECT wn_obj_id as obj_id FROM ( -SELECT ca.*, sr.surface_storage, 'rw_current' as state, wn.obj_id as wn_obj_id, ws._function_hierarchic +SELECT ca.*, sr.surface_storage, 'rw_current' as state, wn.obj_id as wn_obj_id, cfhi.vsacode AS _function_hierarchic FROM qgep_od.catchment_area as ca LEFT JOIN qgep_od.surface_runoff_parameters sr ON ca.obj_id = sr.fk_catchment_area LEFT JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = fk_wastewater_networkelement_rw_current LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE fk_wastewater_networkelement_rw_current IS NOT NULL -- to avoid unconnected catchments UNION ALL -SELECT ca.*, sr.surface_storage, 'ww_current' as state, wn.obj_id as wn_obj_id, ws._function_hierarchic +SELECT ca.*, sr.surface_storage, 'ww_current' as state, wn.obj_id as wn_obj_id, cfhi.vsacode AS _function_hierarchic FROM qgep_od.catchment_area as ca LEFT JOIN qgep_od.surface_runoff_parameters sr ON ca.obj_id = sr.fk_catchment_area LEFT JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = fk_wastewater_networkelement_ww_current LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE fk_wastewater_networkelement_ww_current IS NOT NULL -- to avoid unconnected catchments UNION ALL -SELECT ca.*, sr.surface_storage, 'rw_planned' as state, wn.obj_id as wn_obj_id, ws._function_hierarchic +SELECT ca.*, sr.surface_storage, 'rw_planned' as state, wn.obj_id as wn_obj_id, cfhi.vsacode AS _function_hierarchic FROM qgep_od.catchment_area as ca LEFT JOIN qgep_od.surface_runoff_parameters sr ON ca.obj_id = sr.fk_catchment_area LEFT JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = fk_wastewater_networkelement_rw_planned LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE fk_wastewater_networkelement_rw_planned IS NOT NULL -- to avoid unconnected catchments UNION ALL -SELECT ca.*, sr.surface_storage, 'ww_planned' as state, wn.obj_id as wn_obj_id, ws._function_hierarchic +SELECT ca.*, sr.surface_storage, 'ww_planned' as state, wn.obj_id as wn_obj_id, cfhi.vsacode AS _function_hierarchic FROM qgep_od.catchment_area as ca LEFT JOIN qgep_od.surface_runoff_parameters sr ON ca.obj_id = sr.fk_catchment_area LEFT JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = fk_wastewater_networkelement_ww_planned LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE fk_wastewater_networkelement_ww_planned IS NOT NULL -- to avoid unconnected catchments ) as ca; diff --git a/swmm_views/11_vw_swmm_dwf.sql b/swmm_views/11_vw_swmm_dwf.sql index ec55b874..bd093179 100644 --- a/swmm_views/11_vw_swmm_dwf.sql +++ b/swmm_views/11_vw_swmm_dwf.sql @@ -43,31 +43,35 @@ SELECT wn_obj_id as obj_id FROM ( -SELECT ca.*,'current' as state, 'rw_current' as type_ca, wn.obj_id as wn_obj_id, ws._function_hierarchic +SELECT ca.*,'current' as state, 'rw_current' as type_ca, wn.obj_id as wn_obj_id, cfhi.vsacode AS _function_hierarchic FROM qgep_od.catchment_area as ca LEFT JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = fk_wastewater_networkelement_rw_current LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE fk_wastewater_networkelement_rw_current IS NOT NULL -- to avoid unconnected catchments UNION ALL -SELECT ca.*,'planned' as state, 'rw_planned' as type_ca, wn.obj_id as wn_obj_id, ws._function_hierarchic +SELECT ca.*,'planned' as state, 'rw_planned' as type_ca, wn.obj_id as wn_obj_id, cfhi.vsacode AS _function_hierarchic FROM qgep_od.catchment_area as ca LEFT JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = fk_wastewater_networkelement_rw_planned LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE fk_wastewater_networkelement_rw_planned IS NOT NULL -- to avoid unconnected catchments UNION ALL -SELECT ca.*,'current' as state, 'ww_current' as type_ca, wn.obj_id as wn_obj_id, ws._function_hierarchic +SELECT ca.*,'current' as state, 'ww_current' as type_ca, wn.obj_id as wn_obj_id, cfhi.vsacode AS _function_hierarchic FROM qgep_od.catchment_area as ca LEFT JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = fk_wastewater_networkelement_ww_current LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE fk_wastewater_networkelement_ww_current IS NOT NULL -- to avoid unconnected catchments UNION ALL -SELECT ca.*,'planned' as state, 'ww_planned' as type_ca, wn.obj_id as wn_obj_id, ws._function_hierarchic +SELECT ca.*,'planned' as state, 'ww_planned' as type_ca, wn.obj_id as wn_obj_id, cfhi.vsacode AS _function_hierarchic FROM qgep_od.catchment_area as ca LEFT JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = fk_wastewater_networkelement_ww_planned LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE fk_wastewater_networkelement_ww_planned IS NOT NULL -- to avoid unconnected catchments ) as ca; diff --git a/swmm_views/12_vw_swmm_raingages.sql b/swmm_views/12_vw_swmm_raingages.sql index 80ae0133..8437a947 100644 --- a/swmm_views/12_vw_swmm_raingages.sql +++ b/swmm_views/12_vw_swmm_raingages.sql @@ -15,31 +15,35 @@ SELECT wn_obj_id as obj_id FROM ( -SELECT ca.*,'current' as state, wn.obj_id as wn_obj_id, ws._function_hierarchic +SELECT ca.*,'current' as state, wn.obj_id as wn_obj_id, cfhi.vsacode AS _function_hierarchic FROM qgep_od.catchment_area as ca LEFT JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = fk_wastewater_networkelement_rw_current LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE fk_wastewater_networkelement_rw_current IS NOT NULL -- to avoid unconnected catchments UNION -SELECT ca.*,'planned' as state, wn.obj_id as wn_obj_id, ws._function_hierarchic +SELECT ca.*,'planned' as state, wn.obj_id as wn_obj_id, cfhi.vsacode AS _function_hierarchic FROM qgep_od.catchment_area as ca LEFT JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = fk_wastewater_networkelement_rw_planned LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE fk_wastewater_networkelement_rw_planned IS NOT NULL -- to avoid unconnected catchments UNION -SELECT ca.*,'current' as state, wn.obj_id as wn_obj_id, ws._function_hierarchic +SELECT ca.*,'current' as state, wn.obj_id as wn_obj_id, cfhi.vsacode AS _function_hierarchic FROM qgep_od.catchment_area as ca LEFT JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = fk_wastewater_networkelement_ww_current LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE fk_wastewater_networkelement_ww_current IS NOT NULL -- to avoid unconnected catchments UNION -SELECT ca.*,'planned' as state, wn.obj_id as wn_obj_id, ws._function_hierarchic +SELECT ca.*,'planned' as state, wn.obj_id as wn_obj_id, cfhi.vsacode AS _function_hierarchic FROM qgep_od.catchment_area as ca LEFT JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = fk_wastewater_networkelement_ww_planned LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE fk_wastewater_networkelement_ww_planned IS NOT NULL -- to avoid unconnected catchments ) as ca; diff --git a/swmm_views/13_vw_swmm_infiltrations.sql b/swmm_views/13_vw_swmm_infiltrations.sql index fd319c85..cdd8f125 100644 --- a/swmm_views/13_vw_swmm_infiltrations.sql +++ b/swmm_views/13_vw_swmm_infiltrations.sql @@ -18,17 +18,19 @@ SELECT wn_obj_id as obj_id FROM ( -SELECT ca.*,'current' as state, wn.obj_id as wn_obj_id, ws._function_hierarchic +SELECT ca.*,'current' as state, wn.obj_id as wn_obj_id, cfhi.vsacode AS _function_hierarchic FROM qgep_od.catchment_area as ca LEFT JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = fk_wastewater_networkelement_rw_current LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE fk_wastewater_networkelement_rw_current IS NOT NULL -- to avoid unconnected catchments UNION ALL -SELECT ca.*,'planned' as state, wn.obj_id as wn_obj_id, ws._function_hierarchic +SELECT ca.*,'planned' as state, wn.obj_id as wn_obj_id, cfhi.vsacode AS _function_hierarchic FROM qgep_od.catchment_area as ca LEFT JOIN qgep_od.wastewater_networkelement ne on ne.obj_id = fk_wastewater_networkelement_rw_planned LEFT JOIN qgep_od.wastewater_node wn on wn.obj_id = ne.obj_id LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = ne.fk_wastewater_structure +LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE fk_wastewater_networkelement_rw_planned IS NOT NULL -- to avoid unconnected catchments ) as ca; diff --git a/swmm_views/16_vw_swmm_pumps.sql b/swmm_views/16_vw_swmm_pumps.sql index 41a38d0f..53f0dfd7 100644 --- a/swmm_views/16_vw_swmm_pumps.sql +++ b/swmm_views/16_vw_swmm_pumps.sql @@ -19,12 +19,12 @@ SELECT of.identifier, CASE WHEN oc.obj_id IS NULL --'yes; - THEN 'No curve will be created for this pump, it has no overflow_char' - WHEN vl_oc_dig.vsacode != 6223 --'yes; - THEN 'No curve will be created for this pump, overflow_char_digital not equal to yes' - WHEN vl_oc_ki.vsacode != 6220 --'hq; - THEN concat(pu.obj_id, 'No curve will be created for this pump, kind_overflow_char is not equal to H/Q, Q/Q relations are not supported by SWMM') - ELSE NULL + THEN 'No curve will be created for this pump, it has no overflow_char' + WHEN vl_oc_dig.vsacode != 6223 --'yes; + THEN 'No curve will be created for this pump, overflow_char_digital not equal to yes' + WHEN vl_oc_ki.vsacode != 6220 --'hq; + THEN concat(pu.obj_id, 'No curve will be created for this pump, kind_overflow_char is not equal to H/Q, Q/Q relations are not supported by SWMM') + ELSE NULL END ) as description, pu.obj_id::varchar as tag, @@ -38,12 +38,12 @@ SELECT END as hierarchy, wn.obj_id as obj_id FROM qgep_od.pump pu -LEFT JOIN qgep_od.overflow of ON pu.obj_id = of.obj_id -LEFT JOIN qgep_od.overflow_char oc ON of.fk_overflow_char = oc.obj_id -LEFT JOIN qgep_vl.overflow_char_overflow_char_digital vl_oc_dig ON oc.overflow_char_digital = vl_oc_dig.code -LEFT JOIN qgep_vl.overflow_char_kind_overflow_char vl_oc_ki ON oc.kind_overflow_char = vl_oc_ki.code -LEFT JOIN qgep_od.wastewater_node wn ON wn.obj_id = of.fk_wastewater_node -LEFT JOIN qgep_od.wastewater_structure ws ON ws.fk_main_wastewater_node = wn.obj_id -LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code -LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic + LEFT JOIN qgep_od.overflow of ON pu.obj_id = of.obj_id + LEFT JOIN qgep_od.overflow_char oc ON of.fk_overflow_char = oc.obj_id + LEFT JOIN qgep_vl.overflow_char_overflow_char_digital vl_oc_dig ON oc.overflow_char_digital = vl_oc_dig.code + LEFT JOIN qgep_vl.overflow_char_kind_overflow_char vl_oc_ki ON oc.kind_overflow_char = vl_oc_ki.code + LEFT JOIN qgep_od.wastewater_node wn ON wn.obj_id = of.fk_wastewater_node + LEFT JOIN qgep_od.wastewater_structure ws ON ws.fk_main_wastewater_node = wn.obj_id + LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code + LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959); diff --git a/swmm_views/18_vw_swmm_storages.sql b/swmm_views/18_vw_swmm_storages.sql index e70504bb..ae0213f7 100644 --- a/swmm_views/18_vw_swmm_storages.sql +++ b/swmm_views/18_vw_swmm_storages.sql @@ -176,14 +176,14 @@ SELECT END as hierarchy, wn.obj_id as obj_id FROM qgep_od.prank_weir pw -LEFT JOIN qgep_od.overflow of ON pw.obj_id = of.obj_id -LEFT JOIN qgep_od.overflow_char oc ON of.fk_overflow_char = oc.obj_id -LEFT JOIN qgep_vl.overflow_char_overflow_char_digital vl_oc_dig ON oc.overflow_char_digital = vl_oc_dig.code -LEFT JOIN qgep_vl.overflow_char_kind_overflow_char vL_oc_ki ON oc.kind_overflow_char = vL_oc_ki.code -LEFT JOIN qgep_od.wastewater_node wn ON wn.obj_id = of.fk_wastewater_node -LEFT JOIN qgep_od.wastewater_structure ws ON ws.fk_main_wastewater_node = wn.obj_id -LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code -LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic + LEFT JOIN qgep_od.overflow of ON pw.obj_id = of.obj_id + LEFT JOIN qgep_od.overflow_char oc ON of.fk_overflow_char = oc.obj_id + LEFT JOIN qgep_vl.overflow_char_overflow_char_digital vl_oc_dig ON oc.overflow_char_digital = vl_oc_dig.code + LEFT JOIN qgep_vl.overflow_char_kind_overflow_char vL_oc_ki ON oc.kind_overflow_char = vL_oc_ki.code + LEFT JOIN qgep_od.wastewater_node wn ON wn.obj_id = of.fk_wastewater_node + LEFT JOIN qgep_od.wastewater_structure ws ON ws.fk_main_wastewater_node = wn.obj_id + LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code + LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959) -AND vl_oc_dig.vsacode = 6223 --'yes; -AND vL_oc_ki.vsacode = 6220; -- h/q relations (Q/Q relations are not supported by SWMM) + AND vl_oc_dig.vsacode = 6223 --'yes; + AND vL_oc_ki.vsacode = 6220; -- h/q relations (Q/Q relations are not supported by SWMM) diff --git a/swmm_views/19_vw_swmm_outlets.sql b/swmm_views/19_vw_swmm_outlets.sql index 2443a007..c9b95b64 100644 --- a/swmm_views/19_vw_swmm_outlets.sql +++ b/swmm_views/19_vw_swmm_outlets.sql @@ -19,14 +19,14 @@ SELECT END as hierarchy, wn.obj_id as obj_id FROM qgep_od.prank_weir pw -LEFT JOIN qgep_od.overflow of ON pw.obj_id = of.obj_id -LEFT JOIN qgep_od.overflow_char oc ON of.fk_overflow_char = oc.obj_id -LEFT JOIN qgep_vl.overflow_char_overflow_char_digital vL_oc_dig ON oc.overflow_char_digital = vL_oc_dig.code -LEFT JOIN qgep_vl.overflow_char_kind_overflow_char vl_oc_ki ON oc.kind_overflow_char = vl_oc_ki.code -LEFT JOIN qgep_od.wastewater_node wn ON wn.obj_id = of.fk_wastewater_node -LEFT JOIN qgep_od.wastewater_structure ws ON ws.fk_main_wastewater_node = wn.obj_id -LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code -LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic + LEFT JOIN qgep_od.overflow of ON pw.obj_id = of.obj_id + LEFT JOIN qgep_od.overflow_char oc ON of.fk_overflow_char = oc.obj_id + LEFT JOIN qgep_vl.overflow_char_overflow_char_digital vL_oc_dig ON oc.overflow_char_digital = vL_oc_dig.code + LEFT JOIN qgep_vl.overflow_char_kind_overflow_char vl_oc_ki ON oc.kind_overflow_char = vl_oc_ki.code + LEFT JOIN qgep_od.wastewater_node wn ON wn.obj_id = of.fk_wastewater_node + LEFT JOIN qgep_od.wastewater_structure ws ON ws.fk_main_wastewater_node = wn.obj_id + LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code + LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959) -AND vL_oc_dig.vsacode = 6223 --'yes; -AND vl_oc_ki.vsacode = 6220; -- h/q relations (Q/Q relations are not supported by SWMM) + AND vL_oc_dig.vsacode = 6223 --'yes; + AND vl_oc_ki.vsacode = 6220; -- h/q relations (Q/Q relations are not supported by SWMM) diff --git a/swmm_views/21_vw_swmm_weirs.sql b/swmm_views/21_vw_swmm_weirs.sql index 2212588a..48f81cbe 100644 --- a/swmm_views/21_vw_swmm_weirs.sql +++ b/swmm_views/21_vw_swmm_weirs.sql @@ -26,17 +26,17 @@ SELECT wn.obj_id as obj_id, NULL as message FROM qgep_od.prank_weir pw -LEFT JOIN qgep_od.overflow of ON pw.obj_id = of.obj_id -LEFT JOIN qgep_od.overflow_char oc ON of.fk_overflow_char = oc.obj_id -LEFT JOIN qgep_vl.overflow_char_overflow_char_digital vl_oc_dig ON oc.overflow_char_digital = vl_oc_dig.code -LEFT JOIN qgep_vl.overflow_char_kind_overflow_char vl_oc_ki ON oc.kind_overflow_char = vl_oc_ki.code -LEFT JOIN qgep_od.wastewater_node wn ON wn.obj_id = of.fk_wastewater_node -LEFT JOIN qgep_od.wastewater_structure ws ON ws.fk_main_wastewater_node = wn.obj_id -LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code -LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic + LEFT JOIN qgep_od.overflow of ON pw.obj_id = of.obj_id + LEFT JOIN qgep_od.overflow_char oc ON of.fk_overflow_char = oc.obj_id + LEFT JOIN qgep_vl.overflow_char_overflow_char_digital vl_oc_dig ON oc.overflow_char_digital = vl_oc_dig.code + LEFT JOIN qgep_vl.overflow_char_kind_overflow_char vl_oc_ki ON oc.kind_overflow_char = vl_oc_ki.code + LEFT JOIN qgep_od.wastewater_node wn ON wn.obj_id = of.fk_wastewater_node + LEFT JOIN qgep_od.wastewater_structure ws ON ws.fk_main_wastewater_node = wn.obj_id + LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code + LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959) -AND (vl_oc_dig.vsacode != 6223 OR vl_oc_dig.vsacode IS NULL) --'yes; -OR (vl_oc_ki.vsacode != 6220 OR vl_oc_ki.vsacode IS NULL)-- h/q relations (Q/Q relations are not supported by SWMM) + AND (vl_oc_dig.vsacode != 6223 OR vl_oc_dig.vsacode IS NULL) --'yes; + OR (vl_oc_ki.vsacode != 6220 OR vl_oc_ki.vsacode IS NULL)-- h/q relations (Q/Q relations are not supported by SWMM) UNION ALL @@ -66,12 +66,12 @@ SELECT wn.obj_id as obj_id, concat('Leaping weirs are not supported by SWMM, ', lw.obj_id, 'see: https://swmm5.org/2013/07/19/leaping-weir-example-in-swmm-5-and-infoswmm-alternative/') as message FROM qgep_od.leapingweir lw -LEFT JOIN qgep_od.overflow of ON lw.obj_id = of.obj_id -LEFT JOIN qgep_od.overflow_char oc ON of.fk_overflow_char = oc.obj_id -LEFT JOIN qgep_vl.overflow_char_overflow_char_digital vl_oc_dig ON oc.overflow_char_digital = vl_oc_dig.code -LEFT JOIN qgep_vl.overflow_char_kind_overflow_char vl_oc_ki ON oc.kind_overflow_char = vl_oc_ki.code -LEFT JOIN qgep_od.wastewater_node wn ON wn.obj_id = of.fk_wastewater_node -LEFT JOIN qgep_od.wastewater_structure ws ON ws.fk_main_wastewater_node = wn.obj_id -LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code -LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic + LEFT JOIN qgep_od.overflow of ON lw.obj_id = of.obj_id + LEFT JOIN qgep_od.overflow_char oc ON of.fk_overflow_char = oc.obj_id + LEFT JOIN qgep_vl.overflow_char_overflow_char_digital vl_oc_dig ON oc.overflow_char_digital = vl_oc_dig.code + LEFT JOIN qgep_vl.overflow_char_kind_overflow_char vl_oc_ki ON oc.kind_overflow_char = vl_oc_ki.code + LEFT JOIN qgep_od.wastewater_node wn ON wn.obj_id = of.fk_wastewater_node + LEFT JOIN qgep_od.wastewater_structure ws ON ws.fk_main_wastewater_node = wn.obj_id + LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code + LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959); diff --git a/swmm_views/22_vw_swmm_curves.sql b/swmm_views/22_vw_swmm_curves.sql index 34f83dba..afaf31e1 100644 --- a/swmm_views/22_vw_swmm_curves.sql +++ b/swmm_views/22_vw_swmm_curves.sql @@ -23,19 +23,19 @@ CREATE OR REPLACE VIEW qgep_swmm.vw_curves AS END as hierarchy, wn.obj_id as obj_id FROM qgep_od.hq_relation hq -LEFT JOIN qgep_od.overflow_char oc ON hq.fk_overflow_char = oc.obj_id -LEFT JOIN qgep_vl.overflow_char_overflow_char_digital vl_oc_dig ON oc.overflow_char_digital = vl_oc_dig.code -LEFT JOIN qgep_vl.overflow_char_kind_overflow_char vl_oc_ki ON oc.kind_overflow_char = vl_oc_ki.code -LEFT JOIN qgep_od.overflow of ON of.fk_overflow_char = oc.obj_id -LEFT JOIN qgep_od.pump pu ON pu.obj_id = of.obj_id -LEFT JOIN qgep_od.wastewater_node wn ON wn.obj_id = of.fk_wastewater_node -LEFT JOIN qgep_od.wastewater_structure ws ON ws.fk_main_wastewater_node = wn.obj_id -LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code -LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic + LEFT JOIN qgep_od.overflow_char oc ON hq.fk_overflow_char = oc.obj_id + LEFT JOIN qgep_vl.overflow_char_overflow_char_digital vl_oc_dig ON oc.overflow_char_digital = vl_oc_dig.code + LEFT JOIN qgep_vl.overflow_char_kind_overflow_char vl_oc_ki ON oc.kind_overflow_char = vl_oc_ki.code + LEFT JOIN qgep_od.overflow of ON of.fk_overflow_char = oc.obj_id + LEFT JOIN qgep_od.pump pu ON pu.obj_id = of.obj_id + LEFT JOIN qgep_od.wastewater_node wn ON wn.obj_id = of.fk_wastewater_node + LEFT JOIN qgep_od.wastewater_structure ws ON ws.fk_main_wastewater_node = wn.obj_id + LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code + LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959) -AND vl_oc_dig.vsacode = 6223 --'yes; -AND vl_oc_ki.vsacode = 6220 -- h/q relations (Q/Q relations are not supported by SWMM) -AND pu.obj_id IS NOT NULL + AND vl_oc_dig.vsacode = 6223 --'yes; + AND vl_oc_ki.vsacode = 6220 -- h/q relations (Q/Q relations are not supported by SWMM) + AND pu.obj_id IS NOT NULL ORDER BY pu.obj_id, hq.altitude) UNION ALL @@ -60,19 +60,19 @@ UNION ALL END as hierarchy, wn.obj_id as obj_id FROM qgep_od.hq_relation hq -LEFT JOIN qgep_od.overflow_char oc ON hq.fk_overflow_char = oc.obj_id -LEFT JOIN qgep_vl.overflow_char_overflow_char_digital vl_oc_dig ON oc.overflow_char_digital = vl_oc_dig.code -LEFT JOIN qgep_vl.overflow_char_kind_overflow_char vl_oc_ki ON oc.kind_overflow_char = vl_oc_ki.code -LEFT JOIN qgep_od.overflow of ON of.fk_overflow_char = oc.obj_id -LEFT JOIN qgep_od.prank_weir pw ON pw.obj_id = of.obj_id -LEFT JOIN qgep_od.wastewater_node wn ON wn.obj_id = of.fk_wastewater_node -LEFT JOIN qgep_od.wastewater_structure ws ON ws.fk_main_wastewater_node = wn.obj_id -LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code -LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic + LEFT JOIN qgep_od.overflow_char oc ON hq.fk_overflow_char = oc.obj_id + LEFT JOIN qgep_vl.overflow_char_overflow_char_digital vl_oc_dig ON oc.overflow_char_digital = vl_oc_dig.code + LEFT JOIN qgep_vl.overflow_char_kind_overflow_char vl_oc_ki ON oc.kind_overflow_char = vl_oc_ki.code + LEFT JOIN qgep_od.overflow of ON of.fk_overflow_char = oc.obj_id + LEFT JOIN qgep_od.prank_weir pw ON pw.obj_id = of.obj_id + LEFT JOIN qgep_od.wastewater_node wn ON wn.obj_id = of.fk_wastewater_node + LEFT JOIN qgep_od.wastewater_structure ws ON ws.fk_main_wastewater_node = wn.obj_id + LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code + LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959) -AND vl_oc_dig.vsacode = 6223 --'yes; -AND vl_oc_ki.vsacode = 6220 -- h/q relations (Q/Q relations are not supported by SWMM) -AND pw.obj_id IS NOT NULL + AND vl_oc_dig.vsacode = 6223 --'yes; + AND vl_oc_ki.vsacode = 6220 -- h/q relations (Q/Q relations are not supported by SWMM) + AND pw.obj_id IS NOT NULL ORDER BY pw.obj_id, hq.altitude) UNION ALL diff --git a/swmm_views/23_vw_swmm_xsections.sql b/swmm_views/23_vw_swmm_xsections.sql index 1e2ec259..84da065c 100644 --- a/swmm_views/23_vw_swmm_xsections.sql +++ b/swmm_views/23_vw_swmm_xsections.sql @@ -87,7 +87,7 @@ LEFT JOIN qgep_od.wastewater_structure ws ON ws.fk_main_wastewater_node = wn.obj LEFT JOIN qgep_vl.wastewater_structure_status ws_st ON ws.status = ws_st.code LEFT JOIN qgep_vl.channel_function_hierarchic cfhi ON cfhi.code=ws._function_hierarchic WHERE ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959) -AND oc.overflow_char_digital != 6223 --'NO or unknown; -OR oc.kind_overflow_char != 6220 -- Q/Q relation or unknown -AND ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959); + AND oc.overflow_char_digital != 6223 --'NO or unknown; + OR oc.kind_overflow_char != 6220 -- Q/Q relation or unknown + AND ws_st.vsacode IN (6530, 6533, 8493, 6529, 6526, 7959); diff --git a/swmm_views/27_vw_swmm_results.sql b/swmm_views/27_vw_swmm_results.sql index 21e58e1b..09785dcd 100644 --- a/swmm_views/27_vw_swmm_results.sql +++ b/swmm_views/27_vw_swmm_results.sql @@ -1,6 +1,6 @@ CREATE OR REPLACE VIEW qgep_swmm.node_results AS -SELECT ws.obj_id AS ws_obj_id, ma.function AS ma_function, ss.function AS ss_function, +SELECT ws.obj_id AS ws_obj_id, mf.vsacode AS ma_function, ssf.vsacode AS ss_function, mp.obj_id AS mp_obj_id, mp.remark AS swmm_simulation_name, md.obj_id AS md_obj_id, ms.obj_id AS ms_obj_id, ms.dimension, ms.remark AS swmm_parameter, @@ -9,7 +9,9 @@ wn.situation_geometry AS geom FROM qgep_od.wastewater_structure ws JOIN qgep_od.wastewater_node wn ON wn.obj_id = ws.fk_main_wastewater_node LEFT JOIN qgep_od.manhole ma ON ma.obj_id = ws.obj_id +LEFT JOIN qgep_vl.manhole_function mf ON mf.code = ma.function LEFT JOIN qgep_od.special_structure ss ON ss.obj_id = ws.obj_id +LEFT JOIN qgep_vl.special_structure_function ssf ON ssf.code = ss.function LEFT JOIN qgep_od.measuring_point mp ON mp.fk_wastewater_structure = ws.obj_id LEFT JOIN qgep_od.measuring_device md ON md.fk_measuring_point = mp.obj_id LEFT JOIN qgep_od.measurement_series ms ON ms.fk_measuring_point = mp.obj_id @@ -32,4 +34,4 @@ LEFT JOIN qgep_od.measuring_device md ON md.fk_measuring_point = mp.obj_id LEFT JOIN qgep_od.measurement_series ms ON ms.fk_measuring_point = mp.obj_id LEFT JOIN qgep_od.measurement_result mr ON mr.fk_measurement_series = ms.obj_id WHERE md.remark = 'SWMM Simulation' -ORDER BY mp.obj_id, mr.time; \ No newline at end of file +ORDER BY mp.obj_id, mr.time; diff --git a/view/create_views.py b/view/create_views.py index 93adc390..0f7c45c5 100755 --- a/view/create_views.py +++ b/view/create_views.py @@ -46,12 +46,20 @@ def create_views(srid: int, drop_views(pg_service) + run_sql('view/vw_dictionary_value_list.sql', pg_service, variables) + SingleInheritance('qgep_od.structure_part', 'qgep_od.access_aid', view_name='vw_access_aid', pg_service=pg_service, pkey_default_value=True, inner_defaults={'identifier': 'obj_id'}).create() SingleInheritance('qgep_od.structure_part', 'qgep_od.benching', view_name='vw_benching', pg_service=pg_service, pkey_default_value=True, inner_defaults={'identifier': 'obj_id'}).create() SingleInheritance('qgep_od.structure_part', 'qgep_od.backflow_prevention', view_name='vw_backflow_prevention', pg_service=pg_service, pkey_default_value=True, inner_defaults={'identifier': 'obj_id'}).create() SingleInheritance('qgep_od.structure_part', 'qgep_od.cover', view_name='vw_cover', pg_service=pg_service, pkey_default_value=True, inner_defaults={'identifier': 'obj_id'}).create() SingleInheritance('qgep_od.structure_part', 'qgep_od.dryweather_downspout', view_name='vw_dryweather_downspout', pg_service=pg_service, pkey_default_value=True, inner_defaults={'identifier': 'obj_id'}).create() SingleInheritance('qgep_od.structure_part', 'qgep_od.dryweather_flume', view_name='vw_dryweather_flume', pg_service=pg_service, pkey_default_value=True, inner_defaults={'identifier': 'obj_id'}).create() + SingleInheritance('qgep_od.structure_part', 'qgep_od.solids_retention', view_name='vw_solids_retention', pg_service=pg_service, pkey_default_value=True, inner_defaults={'identifier': 'obj_id'}).create() + SingleInheritance('qgep_od.structure_part', 'qgep_od.tank_cleaning', view_name='vw_tank_cleaning', pg_service=pg_service, pkey_default_value=True, inner_defaults={'identifier': 'obj_id'}).create() + SingleInheritance('qgep_od.structure_part', 'qgep_od.tank_emptying', view_name='vw_tank_emptying', pg_service=pg_service, pkey_default_value=True, inner_defaults={'identifier': 'obj_id'}).create() + SingleInheritance('qgep_od.structure_part', 'qgep_od.electric_equipment', view_name='vw_electric_equipment', pg_service=pg_service, pkey_default_value=True, inner_defaults={'identifier': 'obj_id'}).create() + SingleInheritance('qgep_od.structure_part', 'qgep_od.electromechanical_equipment', view_name='vw_electromechanical_equipment', pg_service=pg_service, pkey_default_value=True, inner_defaults={'identifier': 'obj_id'}).create() + SingleInheritance('qgep_od.wastewater_structure', 'qgep_od.channel', view_name='vw_channel', pg_service=pg_service).create() SingleInheritance('qgep_od.wastewater_structure', 'qgep_od.manhole', view_name='vw_manhole', pg_service=pg_service).create() SingleInheritance('qgep_od.wastewater_structure', 'qgep_od.discharge_point', view_name='vw_discharge_point', pg_service=pg_service).create() diff --git a/view/drop_views.sql b/view/drop_views.sql index 32a19f20..797d5f96 100644 --- a/view/drop_views.sql +++ b/view/drop_views.sql @@ -1,4 +1,6 @@ + + -- qgep_swmm views DROP VIEW IF EXISTS qgep_swmm.vw_aquifers CASCADE; DROP VIEW IF EXISTS qgep_swmm.vw_conduits CASCADE; @@ -130,3 +132,6 @@ DROP VIEW IF EXISTS qgep_od.vw_individual_surface; DROP VIEW IF EXISTS qgep_od.vw_file; DROP VIEW IF EXISTS qgep_od.vw_change_points; DROP VIEW IF EXISTS qgep_od.vw_catchment_area_connections; + +-- qgep_sys views +DROP VIEW IF EXISTS qgep_sys.dictionary_value_list; diff --git a/view/vw_dictionary_value_list.sql b/view/vw_dictionary_value_list.sql new file mode 100644 index 00000000..04136c13 --- /dev/null +++ b/view/vw_dictionary_value_list.sql @@ -0,0 +1,5 @@ + +CREATE VIEW qgep_sys.dictionary_value_list AS + SELECT p.relname AS vl_name, vl.* + FROM qgep_sys.value_list_base vl, pg_class p + WHERE vl.tableoid = p.oid;