Skip to content

Commit

Permalink
Sql adaptations (#50)
Browse files Browse the repository at this point in the history
* Move alterations from closed sql_fixes to new PR

The not yet working part is now separated

* do not materialize gepknoten

* gepknoten minor fix

* add MATERIALIZED VIEW {ext_schema}.knoten_bauwerksattribute

* unconnectected_node bwrel

* alteration of gesamteinzugsgebiet
  • Loading branch information
cymed authored Jul 5, 2024
1 parent ece7a7a commit a0da778
Show file tree
Hide file tree
Showing 4 changed files with 84 additions and 25 deletions.
2 changes: 2 additions & 0 deletions datamodel/tww2ag6496/ag64_96_init/004_extensions_od.sql
Original file line number Diff line number Diff line change
Expand Up @@ -28,6 +28,8 @@ COMMENT ON COLUMN tww_od.catchment_area_totals.ag96_sewer_infiltration_water_dim
ALTER TABLE tww_od.catchment_area_totals ADD COLUMN IF NOT EXISTS ag96_waste_water_production_dim decimal(9,3);
COMMENT ON COLUMN tww_od.catchment_area_totals.ag96_waste_water_production_dim IS 'Extension for AG-96/ Erweiterung aus AG-96 /xxx_fr';

ALTER TABLE tww_od.catchment_area_totals ADD COLUMN IF NOT EXISTS ag96_perimeter_geometry geometry(MultiSurface,2056);
COMMENT ON COLUMN tww_od.catchment_area_totals.ag96_waste_water_production_dim IS 'Extension for AG-96/ Erweiterung aus AG-96 /xxx_fr';

-- Bauten Ausserhalb Baugebiet
ALTER TABLE tww_od.building_group
Expand Down
26 changes: 1 addition & 25 deletions datamodel/tww2ag6496/ag64_96_init/005_export_views.sql
Original file line number Diff line number Diff line change
Expand Up @@ -576,7 +576,7 @@ CREATE OR REPLACE VIEW {ext_schema}.sbw_einzugsgebiet
cat.surface_red AS flaeche_reduziert_ist,
cat.ag96_sewer_infiltration_water_dim AS fremdwasseranfall_geplant,
cat.sewer_infiltration_water AS fremdwasseranfall_ist,
ca_agg.perimeter_geometry AS perimeter_ist,
cat.ag96_perimeter_geometry AS perimeter_ist,
cat.ag96_waste_water_production_dim AS schmutzabwasseranfall_geplant,
cat.waste_water_production AS schmutzabwasseranfall_ist,
cat.fk_discharge_point AS einleitstelleref,
Expand All @@ -587,30 +587,6 @@ CREATE OR REPLACE VIEW {ext_schema}.sbw_einzugsgebiet
FROM tww_od.catchment_area_totals cat
LEFT JOIN tww_od.hydraulic_char_data hcd ON hcd.obj_id = cat.fk_hydraulic_char_data
LEFT JOIN tww_od.wastewater_node wn ON hcd.fk_wastewater_node = wn.obj_id
LEFT JOIN tww_od.log_card lc ON lc.fk_pwwf_wastewater_node::text = wn.obj_id::text
LEFT JOIN ( WITH ca AS (
SELECT catchment_area.fk_special_building_ww_current AS fk_log_card,
catchment_area.perimeter_geometry AS geom
FROM tww_od.catchment_area
WHERE catchment_area.fk_special_building_ww_current IS NOT NULL
UNION
SELECT catchment_area.fk_special_building_rw_current AS fk_log_card,
catchment_area.perimeter_geometry AS geom
FROM tww_od.catchment_area
WHERE catchment_area.fk_special_building_rw_current IS NOT NULL
), collector AS (
SELECT main_lc.obj_id,
ca.geom
FROM ca
LEFT JOIN tww_od.log_card lc ON ca.fk_log_card = lc.obj_id
LEFT JOIN tww_od.log_card main_lc ON main_lc.obj_id = lc.fk_main_structure
)
SELECT collector.obj_id,
st_unaryunion(st_collect(collector.geom)) AS perimeter_geometry
FROM collector
GROUP BY collector.obj_id) ca_agg ON ca_agg.obj_id::text = lc.obj_id::text
WHERE cat.surface_area IS NOT NULL;

;


Expand Down
81 changes: 81 additions & 0 deletions datamodel/tww2ag6496/ag64_96_init/006_functions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,81 @@
---------------------------------
-------- Metainformation --------
---------------------------------

CREATE OR REPLACE FUNCTION {ext_schema}.update_last_ag_modification()
RETURNS trigger AS
$BODY$
DECLARE
update_type varchar(3);
BEGIN
BEGIN
SELECT
ag_update_type
INTO update_type
FROM tww_cfg.agxx_last_modification_updater
WHERE username=current_user;
CASE
WHEN update_type IN('wi','both') THEN NEW.ag64_last_modification=now();
ELSE NULL;
END CASE;
CASE
WHEN update_type IN('gep','both') THEN NEW.ag96_last_modification=now();
ELSE NULL;
END CASE;
END;
RETURN NEW;
END;
$BODY$
LANGUAGE plpgsql;

DROP TRIGGER IF EXISTS before_networkelement_change ON tww_od.wastewater_networkelement;
CREATE TRIGGER before_networkelement_change
BEFORE INSERT OR UPDATE
ON tww_od.wastewater_networkelement
FOR EACH ROW
EXECUTE FUNCTION {ext_schema}.update_last_ag_modification();

DROP TRIGGER IF EXISTS before_overflow_change ON tww_od.overflow;
CREATE TRIGGER before_overflow_change
BEFORE INSERT OR UPDATE
ON tww_od.overflow
FOR EACH ROW
EXECUTE FUNCTION {ext_schema}.update_last_ag_modification();


CREATE OR REPLACE FUNCTION {ext_schema}.update_catchment_area_totals_geoms
(_obj_id varchar(16),_all boolean DEFAULT FALSE)
RETURNS VOID AS
$BODY$
BEGIN
UPDATE tww_od.catchment_area_totals cat
SET ag96_perimeter_geometry =ca_agg.perimeter_geometry
FROM
( WITH ca AS
(
SELECT catchment_area.fk_special_building_ww_current AS fk_log_card,
catchment_area.perimeter_geometry AS geom
FROM tww_od.catchment_area
WHERE catchment_area.fk_special_building_ww_current IS NOT NULL
UNION
SELECT catchment_area.fk_special_building_rw_current AS fk_log_card,
catchment_area.perimeter_geometry AS geom
FROM tww_od.catchment_area
WHERE catchment_area.fk_special_building_rw_current IS NOT NULL
)
SELECT ca_tot.obj_id,
ST_Multi(ST_ForceCurve(ST_UnaryUnion(st_Collect(ca.geom)))) AS perimeter_geometry
FROM ca
LEFT JOIN tww_od.log_card lc ON ca.fk_log_card = lc.obj_id
LEFT JOIN tww_od.log_card main_lc ON main_lc.obj_id = lc.fk_main_structure
LEFT JOIN tww_od.wastewater_node wn ON main_lc.fk_pwwf_wastewater_node::text = wn.obj_id::text
LEFT JOIN tww_od.hydraulic_char_data hcd ON hcd.fk_wastewater_node = wn.obj_id
LEFT JOIN tww_od.catchment_area_totals ca_tot ON hcd.obj_id = ca_tot.fk_hydraulic_char_data
WHERE _all OR _obj_id=ca_tot.obj_id
GROUP BY ca_tot.obj_id
) ca_agg
WHERE ca_agg.obj_id::text = cat.obj_id::text;
END;
$BODY$
LANGUAGE plpgsql
VOLATILE;

0 comments on commit a0da778

Please sign in to comment.