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

Fixes rfc_max_forecast issue where view did not exist by creating the view on deploy #635

Merged
merged 1 commit into from
Feb 26, 2024
Merged
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
110 changes: 109 additions & 1 deletion Core/EC2/RDSBastion/scripts/utils/setup_foreign_tables.tftpl
Original file line number Diff line number Diff line change
Expand Up @@ -35,4 +35,112 @@ echo "Creating user mappings for ${user}"
psql -h "${db_host}" -U "${db_username}" -p ${db_port} -d "${db_name}" \
-tAc "CREATE USER MAPPING FOR ${user} SERVER ${foreign_server} OPTIONS (user '${foreign_db_username}', password '${foreign_db_password}');"

%{ endfor ~}
%{ endfor ~}

%{ if foreign_server == "wrds_location" }

psql -h "${db_host}" -U "${db_username}" -p ${db_port} -d "${db_name}" -tAc "\
DROP VIEW IF EXISTS rnr.flow_thresholds;
CREATE VIEW rnr.flow_thresholds AS

WITH

main AS (
SELECT
station.location_id as nws_station_id,
COALESCE(native.action_flow, usgs.action_flow_calc, nrldb.action_flow_calc) as action,
CASE
WHEN native.action_flow IS NOT NULL
THEN 'Native'
WHEN usgs.action_flow_calc IS NOT NULL
THEN 'USGS'
WHEN nrldb.action_flow_calc IS NOT NULL
THEN 'NRLDB'
END as action_source,
COALESCE(native.minor_flow, usgs.minor_flow_calc, nrldb.minor_flow_calc) as minor,
CASE
WHEN native.minor_flow IS NOT NULL
THEN 'Native'
WHEN usgs.minor_flow_calc IS NOT NULL
THEN 'USGS'
WHEN nrldb.minor_flow_calc IS NOT NULL
THEN 'NRLDB'
END as minor_source,
COALESCE(native.moderate_flow, usgs.moderate_flow_calc, nrldb.moderate_flow_calc) as moderate,
CASE
WHEN native.moderate_flow IS NOT NULL
THEN 'Native'
WHEN usgs.moderate_flow_calc IS NOT NULL
THEN 'USGS'
WHEN nrldb.moderate_flow_calc IS NOT NULL
THEN 'NRLDB'
END as moderate_source,
COALESCE(native.major_flow, usgs.major_flow_calc, nrldb.major_flow_calc) as major,
CASE
WHEN native.major_flow IS NOT NULL
THEN 'Native'
WHEN usgs.major_flow_calc IS NOT NULL
THEN 'USGS'
WHEN nrldb.major_flow_calc IS NOT NULL
THEN 'NRLDB'
END as major_source,
COALESCE(native.record_flow, usgs.record_flow_calc, nrldb.record_flow_calc) as record,
CASE
WHEN native.record_flow IS NOT NULL
THEN 'Native'
WHEN usgs.record_flow_calc IS NOT NULL
THEN 'USGS'
WHEN nrldb.record_flow_calc IS NOT NULL
THEN 'NRLDB'
END as record_source
FROM (SELECT DISTINCT location_id FROM external.threshold) AS station
LEFT JOIN external.threshold native
ON native.location_id = station.location_id
AND native.rating_source = 'NONE'
LEFT JOIN external.threshold usgs
ON usgs.location_id = station.location_id
AND usgs.rating_source = 'USGS Rating Depot'
LEFT JOIN external.threshold nrldb
ON nrldb.location_id = station.location_id
AND nrldb.rating_source = 'NRLDB'
)

SELECT * FROM main
WHERE COALESCE(action, minor, moderate, major, record) IS NOT NULL;

-- CREATE STAGE THRESHOLDS VIEW
DROP VIEW IF EXISTS rnr.stage_thresholds;
CREATE VIEW rnr.stage_thresholds AS

WITH

native_stage_thresholds AS (
SELECT
location_id,
action_stage,
minor_stage,
moderate_stage,
major_stage,
record_stage
FROM external.threshold
WHERE rating_source = 'NONE'
)

SELECT
location_id AS nws_station_id,
action_stage as action,
'Native' as action_source,
minor_stage as minor,
'Native' as minor_source,
moderate_stage as moderate,
'Native' as moderate_source,
major_stage as major,
'Native' as major_source,
record_stage as record,
'Native' as record_source
FROM external.threshold station
WHERE rating_source = 'NONE'
AND COALESCE(action_stage, minor_stage, moderate_stage, major_stage, record_stage) IS NOT NULL;
"

%{ endif }
Original file line number Diff line number Diff line change
Expand Up @@ -115,6 +115,7 @@ ORDER BY
location_nwm_crosswalk_dataset_id DESC NULLS LAST;

-- CREATE FLOW_THRESHOLDS VIEW
-- Officially in Core\EC2\RDSBastion\scripts\utils\setup_foreign_tables.tftpl (for automatic execution on deployment), but duplicated here for reference
DROP VIEW IF EXISTS rnr.flow_thresholds;
CREATE VIEW rnr.flow_thresholds AS

Expand Down Expand Up @@ -184,6 +185,7 @@ SELECT * FROM main
WHERE COALESCE(action, minor, moderate, major, record) IS NOT NULL;

-- CREATE STAGE THRESHOLDS VIEW
-- Officially in Core\EC2\RDSBastion\scripts\utils\setup_foreign_tables.tftpl (for automatic execution on deployment), but duplicated here for reference
DROP VIEW IF EXISTS rnr.stage_thresholds;
CREATE VIEW rnr.stage_thresholds AS

Expand Down Expand Up @@ -212,7 +214,7 @@ SELECT
major_stage as major,
'Native' as major_source,
record_stage as record,
'Native' as record_source,
'Native' as record_source
FROM external.threshold station
WHERE rating_source = 'NONE'
AND COALESCE(action_stage, minor_stage, moderate_stage, major_stage, record_stage) IS NOT NULL;