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

update sigip extension #9

Closed
wants to merge 4 commits into from
Closed
Show file tree
Hide file tree
Changes from all 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
37 changes: 37 additions & 0 deletions extensions/sigip/damage/damage.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,37 @@
CREATE TABLE qwat_od.damage
(
id serial NOT NULL,
fk_cause integer NOT NULL,
fk_pipe integer,
widespread_damage boolean NOT NULL,
detection_date date,
repair_date date,
_repaired boolean,
address text,
pipe_replaced boolean,
description text,
repair text,
geometry geometry(Point,21781),
label_1_visible smallint DEFAULT 1,
label_1_x double precision,
label_1_y double precision,
label_1_rotation double precision,
label_1_text character varying(120),
label_2_visible smallint DEFAULT 1,
label_2_x double precision,
label_2_y double precision,
label_2_rotation double precision,
label_2_text character varying(120),
CONSTRAINT damage_pkey PRIMARY KEY (id)
)
WITH (
OIDS=TRUE
);
ALTER TABLE qwat_od.damage
OWNER TO postgres;
GRANT ALL ON TABLE qwat_od.damage TO postgres;
GRANT SELECT, REFERENCES, TRIGGER ON TABLE qwat_od.damage TO qwat_viewer;
GRANT ALL ON TABLE qwat_od.damage TO qwat_user;
GRANT ALL ON TABLE qwat_od.damage TO qwat_manager;
COMMENT ON TABLE qwat_od.damage
IS 'pipe damage';
8 changes: 8 additions & 0 deletions extensions/sigip/drop_views.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@

DROP VIEW IF EXISTS qwat_sigip.vw_export_damage;
DROP VIEW IF EXISTS qwat_sigip.vw_export_hydrant;
DROP VIEW IF EXISTS qwat_sigip.vw_export_installation;
DROP VIEW IF EXISTS qwat_sigip.vw_export_leak;
DROP VIEW IF EXISTS qwat_sigip.vw_export_part;
DROP VIEW IF EXISTS qwat_sigip.vw_export_pipe;
DROP VIEW IF EXISTS qwat_sigip.vw_export_valve;
14 changes: 14 additions & 0 deletions extensions/sigip/insert_views.sh
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
#!/usr/bin/env bash

# Exit on error
set -e

DIR="$( cd "$( dirname "${BASH_SOURCE[0]}" )" && pwd )"

psql -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/views/damage.sql
psql -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/views/hydrant.sql
psql -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/views/installation.sql
psql -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/views/leak.sql
psql -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/views/part.sql
psql -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/views/pipe.sql
psql -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/views/valve.sql
11 changes: 11 additions & 0 deletions extensions/sigip/sigip.sh
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
#!/usr/bin/env bash

# Exit on error
set -e

DIR="$( cd "$( dirname "${BASH_SOURCE[0]}" )" && pwd )"

psql -c "CREATE SCHEMA IF NOT EXISTS qwat_sigip;"
psql -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/damage/damage.sql

${DIR}/insert_views.sh
13 changes: 13 additions & 0 deletions extensions/sigip/views/damage.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,13 @@
CREATE OR REPLACE VIEW qwat_sigip.vw_export_damage AS
SELECT damage.id,
pipe.fk_parent AS pipe_id,
damage.geometry
FROM qwat_od.damage
LEFT JOIN qwat_od.vw_export_pipe pipe ON damage.fk_pipe = pipe.id;

ALTER TABLE qwat_sigip.vw_export_damage
OWNER TO postgres;
GRANT ALL ON TABLE qwat_sigip.vw_export_damage TO postgres;
GRANT SELECT, REFERENCES, TRIGGER ON TABLE qwat_sigip.vw_export_damage TO qwat_viewer;
GRANT ALL ON TABLE qwat_sigip.vw_export_damage TO qwat_user;
GRANT ALL ON TABLE qwat_sigip.vw_export_damage TO qwat_manager;
31 changes: 31 additions & 0 deletions extensions/sigip/views/hydrant.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,31 @@
CREATE OR REPLACE VIEW qwat_sigip.vw_export_hydrant AS
SELECT vw_element_hydrant.id,
vw_element_hydrant.identification AS numero,
vw_element_hydrant.year AS annee,
vw_element_hydrant.geometry AS the_geom,
status.value_fr AS statut,
district.name AS commune,
pressurezone.name AS zonepression,
distributor.name AS distributeur,
"precision".value_fr AS "precision"
FROM qwat_od.vw_element_hydrant
LEFT JOIN qwat_vl.status status ON vw_element_hydrant.fk_status = status.id
LEFT JOIN qwat_od.district district ON vw_element_hydrant.fk_district = district.id
LEFT JOIN qwat_vl.hydrant_model_inf model_inf ON vw_element_hydrant.fk_model_inf = model_inf.id
LEFT JOIN qwat_od.pressurezone pressurezone ON vw_element_hydrant.fk_pressurezone = pressurezone.id
LEFT JOIN qwat_vl.hydrant_material material ON vw_element_hydrant.fk_material = material.id
LEFT JOIN qwat_vl."precision" "precision" ON vw_element_hydrant.fk_precision = "precision".id
LEFT JOIN qwat_vl.hydrant_model_sup model_sup ON vw_element_hydrant.fk_model_sup = model_sup.id
LEFT JOIN qwat_vl.object_reference object_reference ON vw_element_hydrant.fk_object_reference = object_reference.id
LEFT JOIN qwat_vl.hydrant_provider provider ON vw_element_hydrant.fk_provider = provider.id
LEFT JOIN qwat_od.distributor distributor ON vw_element_hydrant.fk_distributor = distributor.id
LEFT JOIN qwat_vl.hydrant_output output ON vw_element_hydrant.fk_output = output.id
LEFT JOIN qwat_od.folder folder ON vw_element_hydrant.fk_folder = folder.id
LEFT JOIN qwat_vl.precisionalti precisionalti ON vw_element_hydrant.fk_precisionalti = precisionalti.id;

ALTER TABLE qwat_sigip.vw_export_hydrant
OWNER TO postgres;
GRANT ALL ON TABLE qwat_sigip.vw_export_hydrant TO postgres;
GRANT SELECT, REFERENCES, TRIGGER ON TABLE qwat_sigip.vw_export_hydrant TO qwat_viewer;
GRANT ALL ON TABLE qwat_sigip.vw_export_hydrant TO qwat_user;
GRANT ALL ON TABLE qwat_sigip.vw_export_hydrant TO qwat_manager;
39 changes: 39 additions & 0 deletions extensions/sigip/views/installation.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,39 @@
CREATE OR REPLACE VIEW qwat_sigip.vw_export_installation AS
SELECT vw_element_installation.id,
vw_element_installation.identification,
vw_element_installation._pipe_orientation AS orientation,
vw_element_installation.name AS nom,
vw_element_installation.installation_type,
status.value_fr AS statut,
district.name AS commune,
pressurezone.name AS pressurezone_name,
"precision".value_fr AS "precision",
vw_element_installation.geometry_polygon AS the_geom
FROM qwat_od.vw_element_installation
LEFT JOIN qwat_vl.status status ON vw_element_installation.fk_status = status.id
LEFT JOIN qwat_vl.watertype watertype ON vw_element_installation.fk_watertype = watertype.id
LEFT JOIN qwat_vl.pump_type pump_type ON vw_element_installation.fk_pump_type = pump_type.id
LEFT JOIN qwat_vl.object_reference object_reference ON vw_element_installation.fk_object_reference = object_reference.id
LEFT JOIN qwat_vl.cistern cistern2 ON vw_element_installation.cistern2_fk_type = cistern2.id
LEFT JOIN qwat_vl."precision" "precision" ON vw_element_installation.fk_precision = "precision".id
LEFT JOIN qwat_vl.tank_firestorage tank_firestorage ON vw_element_installation.fk_tank_firestorage = tank_firestorage.id
LEFT JOIN qwat_vl.cistern cistern1 ON vw_element_installation.cistern1_fk_type = cistern1.id
LEFT JOIN qwat_vl.source_type source_type ON vw_element_installation.fk_source_type = source_type.id
LEFT JOIN qwat_vl.source_quality source_quality ON vw_element_installation.fk_source_quality = source_quality.id
LEFT JOIN qwat_od.distributor distributor ON vw_element_installation.fk_distributor = distributor.id
LEFT JOIN qwat_vl.overflow overflow ON vw_element_installation.fk_overflow = overflow.id
LEFT JOIN qwat_vl.pressurecontrol_type pressurecontrol_type ON vw_element_installation.fk_pressurecontrol_type = pressurecontrol_type.id
LEFT JOIN qwat_vl.remote_type remote ON vw_element_installation.fk_remote = remote.id
LEFT JOIN qwat_od.district district ON vw_element_installation.fk_district = district.id
LEFT JOIN qwat_od.pressurezone pressurezone ON vw_element_installation.fk_pressurezone = pressurezone.id
LEFT JOIN qwat_od.folder folder ON vw_element_installation.fk_folder = folder.id
LEFT JOIN qwat_vl.precisionalti precisionalti ON vw_element_installation.fk_precisionalti = precisionalti.id
LEFT JOIN qwat_vl.pump_operating pump_operating ON vw_element_installation.fk_pump_operating = pump_operating.id;

ALTER TABLE qwat_sigip.vw_export_installation
OWNER TO postgres;
GRANT ALL ON TABLE qwat_sigip.vw_export_installation TO postgres;
GRANT SELECT, REFERENCES, TRIGGER ON TABLE qwat_sigip.vw_export_installation TO qwat_viewer;
GRANT ALL ON TABLE qwat_sigip.vw_export_installation TO qwat_user;
GRANT ALL ON TABLE qwat_sigip.vw_export_installation TO qwat_manager;

13 changes: 13 additions & 0 deletions extensions/sigip/views/leak.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,13 @@
CREATE OR REPLACE VIEW qwat_sigip.vw_export_leak AS
SELECT leak.id,
pipe.id AS pipe_id,
leak.geometry
FROM qwat_od.leak
LEFT JOIN qwat_od.vw_export_pipe pipe ON leak.fk_pipe = pipe.id;

ALTER TABLE qwat_sigip.vw_export_leak
OWNER TO postgres;
GRANT ALL ON TABLE qwat_sigip.vw_export_leak TO postgres;
GRANT SELECT, REFERENCES, TRIGGER ON TABLE qwat_sigip.vw_export_leak TO qwat_viewer;
GRANT ALL ON TABLE qwat_sigip.vw_export_leak TO qwat_user;
GRANT ALL ON TABLE qwat_sigip.vw_export_leak TO qwat_manager;
28 changes: 28 additions & 0 deletions extensions/sigip/views/part.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,28 @@
CREATE OR REPLACE VIEW qwat_sigip.vw_export_part AS
SELECT vw_element_part.id,
vw_element_part.identification AS numero,
vw_element_part.orientation,
status.value_fr AS statut,
district.name AS commune,
pressurezone.name AS zonepression,
"precision".value_fr AS "precision",
part_type.value_fr AS part_type,
distributor.name AS distributeur,
vw_element_part.geometry AS the_geom
FROM qwat_od.vw_element_part
LEFT JOIN qwat_vl.status status ON vw_element_part.fk_status = status.id
LEFT JOIN qwat_od.district district ON vw_element_part.fk_pressurezone = district.id
LEFT JOIN qwat_od.pressurezone pressurezone ON vw_element_part.fk_pressurezone = pressurezone.id
LEFT JOIN qwat_vl."precision" "precision" ON vw_element_part.fk_precision = "precision".id
LEFT JOIN qwat_vl.part_type part_type ON vw_element_part.fk_part_type = part_type.id
LEFT JOIN qwat_vl.object_reference object_reference ON vw_element_part.fk_object_reference = object_reference.id
LEFT JOIN qwat_od.distributor distributor ON vw_element_part.fk_distributor = distributor.id
LEFT JOIN qwat_od.folder folder ON vw_element_part.fk_folder = folder.id
LEFT JOIN qwat_vl.precisionalti precisionalti ON vw_element_part.fk_precisionalti = precisionalti.id;

ALTER TABLE qwat_sigip.vw_export_part
OWNER TO postgres;
GRANT ALL ON TABLE qwat_sigip.vw_export_part TO postgres;
GRANT SELECT, REFERENCES, TRIGGER ON TABLE qwat_sigip.vw_export_part TO qwat_viewer;
GRANT ALL ON TABLE qwat_sigip.vw_export_part TO qwat_user;
GRANT ALL ON TABLE qwat_sigip.vw_export_part TO qwat_manager;
42 changes: 42 additions & 0 deletions extensions/sigip/views/pipe.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,42 @@
CREATE OR REPLACE VIEW qwat_sigip.vw_export_pipe AS
SELECT pipe.id,
pipe.year AS annee_const,
pipe.year_rehabilitation AS annee_rehab,
pipe.year_end AS annee_fin,
pipe.tunnel_or_bridge AS tunnel_pont,
pipe.pressure_nominal AS pression_nominale,
pipe.remark AS remarque,
pipe._length2d AS longueur,
pipe.geometry AS the_geom,
status.value_fr AS statut,
function.value_fr AS function,
installmethod.value_fr AS method_install,
district.name AS commune,
pressurezone.name AS zone_pression,
material._displayname_fr AS materiau,
material.diameter_nominal AS diam_nominal,
material.diameter_internal AS diam_interne,
material.diameter_external AS diam_externe,
"precision".value_fr AS "precision",
protection.value_fr AS protection,
distributor.name AS distributeur
FROM qwat_od.pipe
LEFT JOIN qwat_vl.status status ON pipe.fk_status = status.id
LEFT JOIN qwat_vl.pipe_function function ON pipe.fk_function = function.id
LEFT JOIN qwat_vl.pipe_installmethod installmethod ON pipe.fk_installmethod = installmethod.id
LEFT JOIN qwat_od.district district ON pipe.fk_district = district.id
LEFT JOIN qwat_od.pressurezone pressurezone ON pipe.fk_pressurezone = pressurezone.id
LEFT JOIN qwat_vl.pipe_material material ON pipe.fk_material = material.id
LEFT JOIN qwat_vl."precision" "precision" ON pipe.fk_precision = "precision".id
LEFT JOIN qwat_vl.pipe_protection protection ON pipe.fk_protection = protection.id
LEFT JOIN qwat_od.distributor distributor ON pipe.fk_distributor = distributor.id
LEFT JOIN qwat_od.folder folder ON pipe.fk_folder = folder.id
LEFT JOIN qwat_od.node node_b ON pipe.fk_node_b = node_b.id
LEFT JOIN qwat_od.node node_a ON pipe.fk_node_a = node_a.id;

ALTER TABLE qwat_sigip.vw_export_pipe
OWNER TO postgres;
GRANT ALL ON TABLE qwat_sigip.vw_export_pipe TO postgres;
GRANT SELECT, REFERENCES, TRIGGER ON TABLE qwat_sigip.vw_export_pipe TO qwat_viewer;
GRANT ALL ON TABLE qwat_sigip.vw_export_pipe TO qwat_user;
GRANT ALL ON TABLE qwat_sigip.vw_export_pipe TO qwat_manager;
29 changes: 29 additions & 0 deletions extensions/sigip/views/valve.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
CREATE OR REPLACE VIEW qwat_sigip.vw_export_valve AS
SELECT valve.id,
valve.identification AS numero,
distributor.name AS distributeur,
pressurezone.name AS zonepression,
valve_function.value_fr AS fonction,
status.value_fr AS statut,
"precision".value_fr AS "precision",
valve_actuation.value_fr AS actionnement,
district.name AS commune,
valve._pipe_orientation AS orientation,
valve.geometry AS the_geom
FROM qwat_od.valve valve
LEFT JOIN qwat_vl.status status ON valve.fk_status = status.id
LEFT JOIN qwat_od.district district ON valve.fk_district = district.id
LEFT JOIN qwat_od.pressurezone pressurezone ON valve.fk_pressurezone = pressurezone.id
LEFT JOIN qwat_vl.valve_function valve_function ON valve.fk_valve_function = valve_function.id
LEFT JOIN qwat_vl."precision" "precision" ON valve.fk_precision = "precision".id
LEFT JOIN qwat_od.distributor distributor ON valve.fk_distributor = distributor.id
LEFT JOIN qwat_vl.valve_type valve_type ON valve.fk_valve_type = valve_type.id
LEFT JOIN qwat_vl.object_reference object_reference ON valve.fk_object_reference = object_reference.id
LEFT JOIN qwat_vl.valve_actuation valve_actuation ON valve.fk_valve_actuation = valve_actuation.id;

ALTER TABLE qwat_sigip.vw_export_valve
OWNER TO postgres;
GRANT ALL ON TABLE qwat_sigip.vw_export_valve TO postgres;
GRANT SELECT, REFERENCES, TRIGGER ON TABLE qwat_sigip.vw_export_valve TO qwat_viewer;
GRANT ALL ON TABLE qwat_sigip.vw_export_valve TO qwat_user;
GRANT ALL ON TABLE qwat_sigip.vw_export_valve TO qwat_manager;
14 changes: 11 additions & 3 deletions ordinary_data/views/rewrite_views.sh
Original file line number Diff line number Diff line change
@@ -1,9 +1,17 @@
#!/usr/bin/env bash

#Exit on error
set -e

DIR="$( cd "$( dirname "${BASH_SOURCE[0]}" )" && pwd )"
DIR=$(git rev-parse --show-toplevel)

psql -v ON_ERROR_STOP=1 -f ${DIR}/drop_views.sql
if [[ $QWAT_SIGIP =~ ON ]]; then
psql -v ON_ERROR_STOP=1 -f ${DIR}/extensions/sigip/drop_views.sql
fi
psql -v ON_ERROR_STOP=1 -f ${DIR}/ordinary_data/views/drop_views.sql

${DIR}/insert_views.sh

${DIR}/ordinary_data/views/insert_views.sh
if [[ $QWAT_CH_VD_SIRE =~ ON ]]; then
${DIR}/extensions/sigip/insert_views.sh
fi
2 changes: 1 addition & 1 deletion update/upgrade_db.sh
Original file line number Diff line number Diff line change
Expand Up @@ -132,7 +132,7 @@ pum baseline -p qwat_comp -t qwat_sys.info -d delta/ -b $VERSION
printf "\n${BLUE}Test and upgrade qwat core${NC}\n\n"
sleep 1s

pum test-and-upgrade -pp qwat_prod -pt qwat_test -pc qwat_comp -t qwat_sys.info -d delta/ -f $TMPFILEDUMP -i columns constraints views sequences indexes triggers functions rules
pum test-and-upgrade -x -pp qwat_prod -pt qwat_test -pc qwat_comp -t qwat_sys.info -d delta/ -f $TMPFILEDUMP -i tables columns constraints views sequences indexes triggers functions rules

# applies local script to test

Expand Down