Skip to content

Commit

Permalink
Merge pull request #220 from cymed/add_vsacode_to_swmm_views
Browse files Browse the repository at this point in the history
Allow vl extensions in SWMM views
  • Loading branch information
ponceta committed Nov 15, 2023
2 parents 164095e + 8aa1cde commit 6efc6c3
Show file tree
Hide file tree
Showing 18 changed files with 280 additions and 134 deletions.
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;
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;
20 changes: 11 additions & 9 deletions swmm_views/04_vw_swmm_conduits.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand All @@ -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
Expand All @@ -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
Expand All @@ -101,35 +101,37 @@ 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'
WHEN from_wn.obj_id IS NULL AND to_wn.obj_id IS NOT NULL THEN 'No from node, a junction was automatically created for the export.'
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
LEFT JOIN qgep_od.reach_point rp_to ON rp_to.obj_id::text = re.fk_reach_point_to::text
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"
Expand Down
20 changes: 12 additions & 8 deletions swmm_views/05_vw_swmm_dividers.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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

Expand 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);
3 changes: 2 additions & 1 deletion swmm_views/07_vw_swmm_losses.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
38 changes: 35 additions & 3 deletions swmm_views/08_vw_swmm_outfalls.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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)
;
Loading

0 comments on commit 6efc6c3

Please sign in to comment.