Skip to content

Commit

Permalink
Merge branch 'master' into delta_1.5.x_dss_rename_xxx_fk_overflow_cha…
Browse files Browse the repository at this point in the history
…racteristic_to_fk_overflow_char
  • Loading branch information
ponceta committed Mar 13, 2024
2 parents 59c77a6 + 6efc6c3 commit 6c1d757
Show file tree
Hide file tree
Showing 30 changed files with 424 additions and 191 deletions.
2 changes: 1 addition & 1 deletion .docker/Dockerfile
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
ARG POSTGIS_VERSION=11-3.2
ARG POSTGIS_VERSION=14-3.2
FROM postgis/postgis:${POSTGIS_VERSION}

# System deps
Expand Down
14 changes: 7 additions & 7 deletions .github/workflows/docker-test-and-push.yaml
Original file line number Diff line number Diff line change
Expand Up @@ -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: |
Expand Down
1 change: 1 addition & 0 deletions 02_oid_generation.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
22 changes: 11 additions & 11 deletions 03_qgep_db_dss.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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),
Expand Down Expand Up @@ -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');
Expand Down Expand Up @@ -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;
Expand Down Expand Up @@ -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);
Expand Down
34 changes: 20 additions & 14 deletions 05_data_model_extensions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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;
Expand Down
2 changes: 1 addition & 1 deletion delta/delta_1.5.8_tbl_swmm_coefficient_friction.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
4 changes: 4 additions & 0 deletions delta/delta_1.6.1_add_ii_to_swmm_outfalls
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
--------
-- View for the swmm module class outfalls now includes infiltration installations
--------
SELECT 1;
10 changes: 10 additions & 0 deletions delta/delta_1.6.1_allow_longer_vl_names.sql
Original file line number Diff line number Diff line change
@@ -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);
20 changes: 20 additions & 0 deletions delta/delta_1.6.1_alter_order_fct_hierarchic.sql
Original file line number Diff line number Diff line change
@@ -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)
Original file line number Diff line number Diff line change
@@ -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

38 changes: 23 additions & 15 deletions swmm_views/02_vw_swmm_junctions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand All @@ -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

Expand All @@ -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
Expand All @@ -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"
Expand Down Expand Up @@ -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
Expand All @@ -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
Expand All @@ -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
Expand All @@ -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;
Loading

0 comments on commit 6c1d757

Please sign in to comment.