Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Automate updates of main cover and main wastewater node #97

Merged
merged 6 commits into from
Jan 19, 2024
Merged
Changes from 3 commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
62 changes: 61 additions & 1 deletion datamodel/app/symbology_functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -104,7 +104,6 @@ $BODY$
LANGUAGE plpgsql
VOLATILE;


-------------------- SYMBOLOGY UPDATE ON CHANNEL TABLE CHANGES ----------------------

CREATE OR REPLACE FUNCTION tww_app.ws_symbology_update_by_channel()
Expand Down Expand Up @@ -263,6 +262,67 @@ BEGIN
END; $BODY$
LANGUAGE plpgsql VOLATILE;

--------------------------------------------------------
-- UPDATE wastewater structure fk_main_cover
-- Argument:
-- * obj_id of wastewater structure
-- * all True to update all
--------------------------------------------------------
CREATE OR REPLACE FUNCTION tww_app.update_wastewater_structure_fk_main_cover(_obj_id text, _all boolean default false)
cymed marked this conversation as resolved.
Show resolved Hide resolved
RETURNS VOID AS
$BODY$
DECLARE
myrec record;

BEGIN
UPDATE tww_od.wastewater_structure ws
SET fk_main_cover = ws_covers.co_obj_id
FROM (
SELECT ws.obj_id, min(co.obj_id) OVER (PARTITION BY ws.obj_id) AS co_obj_id
FROM tww_od.wastewater_structure ws
LEFT JOIN tww_od.structure_part sp ON sp.fk_wastewater_structure = ws.obj_id
LEFT JOIN tww_od.cover co ON sp.obj_id = co.obj_id
LEFT JOIN tww_od.channel ch ON ch.obj_id = ws.obj_id
WHERE (_all OR ws.obj_id = _obj_id ) AND ch.obj_id IS NULL AND ws.fk_main_cover IS NULL
Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

my question here is regarding ws.fk_main_cover IS NULL
if we use _all, don't we expect to run on all?

or can we assume, that we will never need to fix this data?

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Suggestion: 3 input options:

_obj_id: as is
_all : as is
_all_nulls: for automated imports

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I would keep 2, but combine them

_obj_id = XXX => do XXX (don't care about NULL=
_obj_id NULL and _all is false => do only NULLs
_all is TRUE => do all

Copy link
Contributor

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

so calling without args would be the automated import

Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Sounds good. Do we want this setup for all the symbology functions with the arguments _obj_id and _all?

) ws_covers
WHERE ws.obj_id = ws_covers.obj_id;
END

$BODY$
LANGUAGE plpgsql
VOLATILE;

--------------------------------------------------------
-- UPDATE wastewater structure fk_main_wastewater_node
-- Argument:
-- * obj_id of wastewater structure
-- * all True to update all
--------------------------------------------------------

CREATE OR REPLACE FUNCTION tww_app.update_wastewater_structure_fk_main_wastewater_node(_obj_id text, _all boolean default false)
cymed marked this conversation as resolved.
Show resolved Hide resolved
RETURNS VOID AS
$BODY$
DECLARE
myrec record;

BEGIN
UPDATE tww_od.wastewater_structure ws
SET fk_main_wastewater_node = ws_nodes.wn_obj_id
FROM (
SELECT ws.obj_id, min(wn.obj_id) OVER (PARTITION BY ws.obj_id) AS wn_obj_id
FROM tww_od.wastewater_structure ws
LEFT JOIN tww_od.wastewater_networkelement ne ON ne.fk_wastewater_structure = ws.obj_id
LEFT JOIN tww_od.wastewater_node wn ON ne.obj_id = wn.obj_id
LEFT JOIN tww_od.channel ch ON ch.obj_id = ws.obj_id
WHERE (_all OR ws.obj_id = _obj_id ) AND ch.obj_id IS NULL AND ws.fk_main_wastewater_node IS NULL
) ws_nodes
WHERE ws.obj_id = ws_nodes.obj_id;
END

$BODY$
LANGUAGE plpgsql
VOLATILE;

--------------------------------------------------------
-- UPDATE wastewater structure depth
-- Argument:
Expand Down