From a7f6caf0bd33c052aba497a51ad6f188cd50865a Mon Sep 17 00:00:00 2001 From: Simon Norris Date: Tue, 27 Feb 2024 16:12:36 -0800 Subject: [PATCH 01/10] clean up db setup/data loads --- db/README.md | 4 +- db/functions/break_streams.sql | 2 +- db/functions/create_barrier_table.sql | 2 +- db/functions/load_dnstr.sql | 2 +- db/functions/load_upstr.sql | 2 +- db/functions/streamsasmvt.sql | 2 +- db/functions/utmzone.sql | 2 +- db/functions/wcrp_barrier_count.sql | 1 - db/functions/wcrp_barrier_extent.sql | 2 - db/functions/wcrp_barrier_severity.sql | 2 - .../wcrp_habitat_connectivity_status.sql | 3 - db/functions/wsg_crossing_summary.sql | 2 - db/functions/wsg_linear_summary.sql | 1 - db/schemas.sql | 11 + db/schemas/schemas.sql | 3 - db/setup.sh | 21 - db/tables/cabd.sql | 4 - db/tables/crossings.sql | 3 - db/tables/crossings_upstr_dnstr.sql | 4 - db/tables/crossings_upstream_access.sql | 2 - db/tables/crossings_upstream_habitat.sql | 4 - db/tables/gradient_barriers.sql | 14 +- db/tables/habitat_linear.sql | 8 - db/tables/log.sql | 10 +- db/tables/observations.sql | 18 +- db/tables/parameters.sql | 9 +- db/tables/streams.sql | 3 - db/tables/streams_upstr_dnstr.sql | 5 - db/tables/transport_line.sql | 132 +++++ db/tables/user.sql | 11 - db/views/01_dams_vw.sql | 4 - db/views/01_streams.sql | 7 - db/views/02_crossings.sql | 69 ++- db/views/03_observations_vw.sql | 2 - db/views/04_falls_vw.sql | 5 - db/views/05_streams_spp.sql | 468 ++++++++++++++++++ db/views/11_streams_bt_vw.sql | 49 -- db/views/12_streams_ch_vw.sql | 49 -- db/views/13_streams_cm_vw.sql | 49 -- db/views/14_streams_co_vw.sql | 49 -- db/views/15_streams_pk_vw.sql | 49 -- db/views/16_streams_salmon_vw.sql | 81 --- db/views/17_streams_sk_vw.sql | 49 -- db/views/18_streams_st_vw.sql | 49 -- db/views/19_streams_wct_vw.sql | 49 -- ...water_fish_habitat_accessibility_model.sql | 3 - db/views/wcrp_barrier_count_vw.sql | 1 - .../wcrp_habitat_connectivity_status_vw.sql | 3 - db/views/wsg_crossing_summary.sql | 5 - db/views/wsg_linear_summary.sql | 4 +- jobs/setup | 72 +++ jobs/test | 43 -- .../modelled_stream_crossings/Makefile | 55 -- model/01_access/pscis/pscis.sh | 41 +- 54 files changed, 748 insertions(+), 796 deletions(-) create mode 100644 db/schemas.sql delete mode 100644 db/schemas/schemas.sql delete mode 100755 db/setup.sh create mode 100644 db/tables/transport_line.sql create mode 100644 db/views/05_streams_spp.sql delete mode 100644 db/views/11_streams_bt_vw.sql delete mode 100644 db/views/12_streams_ch_vw.sql delete mode 100644 db/views/13_streams_cm_vw.sql delete mode 100644 db/views/14_streams_co_vw.sql delete mode 100644 db/views/15_streams_pk_vw.sql delete mode 100644 db/views/16_streams_salmon_vw.sql delete mode 100644 db/views/17_streams_sk_vw.sql delete mode 100644 db/views/18_streams_st_vw.sql delete mode 100644 db/views/19_streams_wct_vw.sql create mode 100755 jobs/setup delete mode 100755 jobs/test diff --git a/db/README.md b/db/README.md index 08549d69..a2bf83a2 100644 --- a/db/README.md +++ b/db/README.md @@ -8,4 +8,6 @@ Additional internal tables are created by model scripts. ## Usage - ./setup.sh \ No newline at end of file +From repository root, with $DATABASE_URL connection defined as db superuser: + + .jobs/setup \ No newline at end of file diff --git a/db/functions/break_streams.sql b/db/functions/break_streams.sql index b1e928bb..c60f8db5 100644 --- a/db/functions/break_streams.sql +++ b/db/functions/break_streams.sql @@ -1,4 +1,4 @@ -CREATE OR REPLACE FUNCTION bcfishpass.break_streams(point_table text, wsg text) +CREATE FUNCTION bcfishpass.break_streams(point_table text, wsg text) RETURNS VOID LANGUAGE plpgsql AS $func$ diff --git a/db/functions/create_barrier_table.sql b/db/functions/create_barrier_table.sql index f6add319..73161f89 100644 --- a/db/functions/create_barrier_table.sql +++ b/db/functions/create_barrier_table.sql @@ -1,6 +1,6 @@ -- create table for holding barriers of given type -CREATE OR REPLACE FUNCTION bcfishpass.create_barrier_table(barriertype text) +CREATE FUNCTION bcfishpass.create_barrier_table(barriertype text) RETURNS VOID LANGUAGE plpgsql AS $func$ diff --git a/db/functions/load_dnstr.sql b/db/functions/load_dnstr.sql index 40effd61..6fa5fb21 100644 --- a/db/functions/load_dnstr.sql +++ b/db/functions/load_dnstr.sql @@ -1,6 +1,6 @@ -- compare records in table a and table b, -- and record in output table (as an array) all ids from b that are downstream of given id for table a -CREATE OR REPLACE FUNCTION bcfishpass.load_dnstr( +CREATE FUNCTION bcfishpass.load_dnstr( table_a text, table_a_id text, table_b text, diff --git a/db/functions/load_upstr.sql b/db/functions/load_upstr.sql index 61615881..2c3f48ae 100644 --- a/db/functions/load_upstr.sql +++ b/db/functions/load_upstr.sql @@ -1,6 +1,6 @@ -- compare records in table a and table b, -- and record in output table (as an array) all ids from b that are downstream of given id for table a -CREATE OR REPLACE FUNCTION bcfishpass.load_upstr( +CREATE FUNCTION bcfishpass.load_upstr( table_a text, table_a_id text, table_b text, diff --git a/db/functions/streamsasmvt.sql b/db/functions/streamsasmvt.sql index ccbbecb8..8e82b5a4 100644 --- a/db/functions/streamsasmvt.sql +++ b/db/functions/streamsasmvt.sql @@ -1,4 +1,4 @@ -CREATE OR REPLACE FUNCTION bcfishpass.streamsasmvt( +CREATE FUNCTION bcfishpass.streamsasmvt( z integer, x integer, y integer) RETURNS bytea AS $$ diff --git a/db/functions/utmzone.sql b/db/functions/utmzone.sql index bc1b5fd7..cec6e8bc 100755 --- a/db/functions/utmzone.sql +++ b/db/functions/utmzone.sql @@ -3,7 +3,7 @@ -- DROP FUNCTION utmzone(geometry); -- Usage: SELECT ST_Transform(the_geom, utmzone(ST_Centroid(the_geom)) )FROM sometable; -CREATE OR REPLACE FUNCTION public.utmzone(geometry) +CREATE FUNCTION public.utmzone(geometry) RETURNS integer AS $BODY$ DECLARE diff --git a/db/functions/wcrp_barrier_count.sql b/db/functions/wcrp_barrier_count.sql index 3ca8a776..421d8e28 100644 --- a/db/functions/wcrp_barrier_count.sql +++ b/db/functions/wcrp_barrier_count.sql @@ -1,5 +1,4 @@ -- function to query the view (so it is visible in pgfs) -DROP FUNCTION IF EXISTS postgisftw.wcrp_barrier_count; CREATE FUNCTION postgisftw.wcrp_barrier_count( watershed_group_code TEXT, model_status TEXT default 'ALL' diff --git a/db/functions/wcrp_barrier_extent.sql b/db/functions/wcrp_barrier_extent.sql index 6745d278..7b6daf30 100644 --- a/db/functions/wcrp_barrier_extent.sql +++ b/db/functions/wcrp_barrier_extent.sql @@ -1,5 +1,3 @@ -DROP FUNCTION IF EXISTS postgisftw.wcrp_barrier_extent(TEXT); - CREATE FUNCTION postgisftw.wcrp_barrier_extent(watershed_group_code TEXT) -- watershed_group_code: BULK, LNIC, HORS, BOWR, QUES, CARR, ELKR diff --git a/db/functions/wcrp_barrier_severity.sql b/db/functions/wcrp_barrier_severity.sql index 8007efe9..58f16c1f 100644 --- a/db/functions/wcrp_barrier_severity.sql +++ b/db/functions/wcrp_barrier_severity.sql @@ -1,5 +1,3 @@ -DROP FUNCTION IF EXISTS postgisftw.wcrp_barrier_severity(text); - CREATE FUNCTION postgisftw.wcrp_barrier_severity(watershed_group_code TEXT) -- watershed_group_code: BULK, LNIC, HORS, BOWR, QUES, CARR, ELKR diff --git a/db/functions/wcrp_habitat_connectivity_status.sql b/db/functions/wcrp_habitat_connectivity_status.sql index bc2cdd98..c845bb51 100644 --- a/db/functions/wcrp_habitat_connectivity_status.sql +++ b/db/functions/wcrp_habitat_connectivity_status.sql @@ -1,7 +1,4 @@ -- report on total modelled habitat vs accessible modelled habitat - -DROP FUNCTION IF EXISTS postgisftw.wcrp_habitat_connectivity_status(TEXT,TEXT); - CREATE OR REPLACE FUNCTION postgisftw.wcrp_habitat_connectivity_status( watershed_group_code TEXT, habitat_type TEXT default 'ALL' diff --git a/db/functions/wsg_crossing_summary.sql b/db/functions/wsg_crossing_summary.sql index a66fba91..46f27ac9 100644 --- a/db/functions/wsg_crossing_summary.sql +++ b/db/functions/wsg_crossing_summary.sql @@ -2,8 +2,6 @@ -- - total -- - accessible (per model) -- - with spawning rearing habitat upstream (per model) - -DROP FUNCTION IF EXISTS bcfishpass.wsg_crossing_summary(); CREATE FUNCTION bcfishpass.wsg_crossing_summary() RETURNS table ( watershed_group_code text, diff --git a/db/functions/wsg_linear_summary.sql b/db/functions/wsg_linear_summary.sql index 1091bfbe..fe1ad840 100644 --- a/db/functions/wsg_linear_summary.sql +++ b/db/functions/wsg_linear_summary.sql @@ -10,7 +10,6 @@ -- - spawning or rearing habitat not isolated by dam or a known pscis barrier (accessible_a) -- - spawning or rearing habitat not isolated by all anthropogenic barriers (observed and modelled) (accessible_b) -DROP FUNCTION IF EXISTS bcfishpass.wsg_linear_summary(); CREATE FUNCTION bcfishpass.wsg_linear_summary() RETURNS table ( watershed_group_code text, diff --git a/db/schemas.sql b/db/schemas.sql new file mode 100644 index 00000000..f6812250 --- /dev/null +++ b/db/schemas.sql @@ -0,0 +1,11 @@ +create schema bcfishpass; +create schema cabd; +create schema whse_admin_boundaries; +create schema whse_cadastre; +create schema whse_environmental_monitoring; +create schema whse_forest_tenure; +create schema whse_forest_vegetation; +create schema whse_imagery_and_base_maps; +create schema whse_legal_admin_boundaries; +create schema whse_mineral_tenure; +create schema whse_tantalis; \ No newline at end of file diff --git a/db/schemas/schemas.sql b/db/schemas/schemas.sql deleted file mode 100644 index 6485cc9d..00000000 --- a/db/schemas/schemas.sql +++ /dev/null @@ -1,3 +0,0 @@ -create schema if not exists bcfishpass; -create schema if not exists cabd; -create schema if not exists temp; \ No newline at end of file diff --git a/db/setup.sh b/db/setup.sh deleted file mode 100755 index accedc0d..00000000 --- a/db/setup.sh +++ /dev/null @@ -1,21 +0,0 @@ -#!/bin/bash -set -euxo pipefail - -PSQL="psql $DATABASE_URL -v ON_ERROR_STOP=1" - -# load schemas, tables functions -for sql in schemas/*.sql ; do - $PSQL -f "$sql" -done - -for sql in tables/*.sql ; do - $PSQL -f "$sql" -done - -for sql in views/*.sql ; do - $PSQL -f "$sql" -done - -for sql in functions/*.sql ; do - $PSQL -f "$sql" -done \ No newline at end of file diff --git a/db/tables/cabd.sql b/db/tables/cabd.sql index 5154535d..b6f096c0 100644 --- a/db/tables/cabd.sql +++ b/db/tables/cabd.sql @@ -1,6 +1,4 @@ -- dams -drop table if exists cabd.dams cascade; - create table cabd.dams ( cabd_id text , use_pollution_code integer , @@ -108,8 +106,6 @@ create table cabd.dams ( ); -- waterfalls -drop table if exists cabd.waterfalls cascade; - create table cabd.waterfalls ( cabd_id text , fall_name_fr text , diff --git a/db/tables/crossings.sql b/db/tables/crossings.sql index 0d7848a7..20719bd1 100644 --- a/db/tables/crossings.sql +++ b/db/tables/crossings.sql @@ -7,9 +7,6 @@ -- 3. Modelled crossings (culverts and bridges) -- 4. Other ? -- -------------- - -drop table if exists bcfishpass.crossings cascade; - create table bcfishpass.crossings ( -- Note how the aggregated crossing id combines the various ids to create a unique integer, after assigning PSCIS crossings their source crossing id diff --git a/db/tables/crossings_upstr_dnstr.sql b/db/tables/crossings_upstr_dnstr.sql index 7bea03f8..23ab0be8 100644 --- a/db/tables/crossings_upstr_dnstr.sql +++ b/db/tables/crossings_upstr_dnstr.sql @@ -1,24 +1,20 @@ -- note other crossings/barriers upstream / downstream of crossings in crossings table / barriers anth table -drop table if exists bcfishpass.crossings_dnstr_crossings cascade; create table bcfishpass.crossings_dnstr_crossings ( aggregated_crossings_id text primary key, features_dnstr text[] ); -drop table if exists bcfishpass.crossings_dnstr_barriers_anthropogenic cascade; create table bcfishpass.crossings_dnstr_barriers_anthropogenic ( aggregated_crossings_id text primary key, features_dnstr text[] ); -drop table if exists bcfishpass.crossings_upstr_barriers_anthropogenic cascade; create table bcfishpass.crossings_upstr_barriers_anthropogenic ( aggregated_crossings_id text primary key, features_upstr text[] ); -drop table if exists bcfishpass.barriers_anthropogenic_dnstr_barriers_anthropogenic cascade; create table bcfishpass.barriers_anthropogenic_dnstr_barriers_anthropogenic ( barriers_anthropogenic_id text primary key, features_dnstr text[] diff --git a/db/tables/crossings_upstream_access.sql b/db/tables/crossings_upstream_access.sql index 026571fa..a6d6306c 100644 --- a/db/tables/crossings_upstream_access.sql +++ b/db/tables/crossings_upstream_access.sql @@ -1,6 +1,4 @@ -- report on potentially accessible lengths and areas upstream, per species scenario / model -drop table if exists bcfishpass.crossings_upstream_access cascade; - create table bcfishpass.crossings_upstream_access ( aggregated_crossings_id text primary key, watershed_group_code character varying (4), diff --git a/db/tables/crossings_upstream_habitat.sql b/db/tables/crossings_upstream_habitat.sql index b5f0a5e0..33b556bc 100644 --- a/db/tables/crossings_upstream_habitat.sql +++ b/db/tables/crossings_upstream_habitat.sql @@ -1,6 +1,4 @@ -- report on habitat upstream, per species -drop table if exists bcfishpass.crossings_upstream_habitat cascade; - create table bcfishpass.crossings_upstream_habitat ( aggregated_crossings_id text primary key, watershed_group_code character varying (4), @@ -43,8 +41,6 @@ create table bcfishpass.crossings_upstream_habitat ( -- - barriers only -- - currently ch/co/sk/st/wct where they exist in watersheds of interest -- - apply 1.5x multiplier to co rearing in wetlands and all sk rearing -drop table if exists bcfishpass.crossings_upstream_habitat_wcrp cascade; - create table bcfishpass.crossings_upstream_habitat_wcrp ( aggregated_crossings_id text primary key, watershed_group_code character varying (4), diff --git a/db/tables/gradient_barriers.sql b/db/tables/gradient_barriers.sql index b58d4919..a5cf32a6 100644 --- a/db/tables/gradient_barriers.sql +++ b/db/tables/gradient_barriers.sql @@ -1,5 +1,3 @@ -DROP TABLE IF EXISTS bcfishpass.gradient_barriers; - CREATE TABLE bcfishpass.gradient_barriers ( gradient_barrier_id bigint GENERATED ALWAYS AS ((((blue_line_key::bigint + 1) - 354087611) * 10000000) + round(downstream_route_measure::bigint)) STORED PRIMARY KEY, blue_line_key integer , @@ -10,9 +8,9 @@ CREATE TABLE bcfishpass.gradient_barriers ( gradient_class integer ); -create index if not exists grdntbr_blk_idx on bcfishpass.gradient_barriers (blue_line_key); -create index if not exists grdntbr_wsgcode_idx on bcfishpass.gradient_barriers (watershed_group_code); -create index if not exists grdntbr_wscode_gidx on bcfishpass.gradient_barriers using gist (wscode_ltree); -create index if not exists grdntbr_wscode_bidx on bcfishpass.gradient_barriers using btree (wscode_ltree); -create index if not exists grdntbr_localcode_gidx on bcfishpass.gradient_barriers using gist (localcode_ltree); -create index if not exists grdntbr_localcode_bidx on bcfishpass.gradient_barriers using btree (localcode_ltree); \ No newline at end of file +create index grdntbr_blk_idx on bcfishpass.gradient_barriers (blue_line_key); +create index grdntbr_wsgcode_idx on bcfishpass.gradient_barriers (watershed_group_code); +create index grdntbr_wscode_gidx on bcfishpass.gradient_barriers using gist (wscode_ltree); +create index grdntbr_wscode_bidx on bcfishpass.gradient_barriers using btree (wscode_ltree); +create index grdntbr_localcode_gidx on bcfishpass.gradient_barriers using gist (localcode_ltree); +create index grdntbr_localcode_bidx on bcfishpass.gradient_barriers using btree (localcode_ltree); \ No newline at end of file diff --git a/db/tables/habitat_linear.sql b/db/tables/habitat_linear.sql index a54d5c8a..a64b916a 100644 --- a/db/tables/habitat_linear.sql +++ b/db/tables/habitat_linear.sql @@ -1,51 +1,43 @@ -drop table if exists bcfishpass.habitat_linear_bt cascade; create table bcfishpass.habitat_linear_bt ( segmented_stream_id text primary key, spawning boolean, rearing boolean ); -drop table if exists bcfishpass.habitat_linear_ch cascade; create table bcfishpass.habitat_linear_ch ( segmented_stream_id text primary key, spawning boolean, rearing boolean ); -drop table if exists bcfishpass.habitat_linear_cm cascade; create table bcfishpass.habitat_linear_cm ( segmented_stream_id text primary key, spawning boolean ); -drop table if exists bcfishpass.habitat_linear_co cascade; create table bcfishpass.habitat_linear_co ( segmented_stream_id text primary key, spawning boolean, rearing boolean ); -drop table if exists bcfishpass.habitat_linear_pk cascade; create table bcfishpass.habitat_linear_pk ( segmented_stream_id text primary key, spawning boolean ); -drop table if exists bcfishpass.habitat_linear_sk cascade; create table bcfishpass.habitat_linear_sk ( segmented_stream_id text primary key, spawning boolean, rearing boolean ); -drop table if exists bcfishpass.habitat_linear_st cascade; create table bcfishpass.habitat_linear_st ( segmented_stream_id text primary key, spawning boolean, rearing boolean ); -drop table if exists bcfishpass.habitat_linear_wct cascade; create table bcfishpass.habitat_linear_wct ( segmented_stream_id text primary key, spawning boolean, diff --git a/db/tables/log.sql b/db/tables/log.sql index 6eb8fc46..6ac77767 100644 --- a/db/tables/log.sql +++ b/db/tables/log.sql @@ -6,7 +6,7 @@ --drop table bcfishpass.parameters_habitat_thresholds_log; --drop table bcfishpass.wsg_linear_summary; --drop table bcfishpass.wsg_crossing_summary; -create table if not exists bcfishpass.log ( +create table bcfishpass.log ( model_run_id serial primary key, model_type text not null, date_completed timestamp not null default CURRENT_TIMESTAMP, @@ -20,13 +20,13 @@ create table if not exists bcfishpass.log ( -- log parameters used for the given model run -create table if not exists bcfishpass.parameters_habitat_method_log ( +create table bcfishpass.parameters_habitat_method_log ( model_run_id integer references bcfishpass.log(model_run_id), watershed_group_code character varying(4), model text ); -create table if not exists bcfishpass.parameters_habitat_thresholds_log ( +create table bcfishpass.parameters_habitat_thresholds_log ( model_run_id integer references bcfishpass.log(model_run_id), species_code text , spawn_gradient_max numeric, @@ -42,7 +42,7 @@ create table if not exists bcfishpass.parameters_habitat_thresholds_log ( rear_lake_ha_min integer ); -create table if not exists bcfishpass.wsg_linear_summary ( +create table bcfishpass.wsg_linear_summary ( model_run_id integer references bcfishpass.log(model_run_id), watershed_group_code text, length_total numeric, @@ -112,7 +112,7 @@ create table if not exists bcfishpass.wsg_linear_summary ( length_spawning_rearing_wct_accessible_b numeric ); -create table if not exists bcfishpass.wsg_crossing_summary ( +create table bcfishpass.wsg_crossing_summary ( model_run_id integer references bcfishpass.log(model_run_id), watershed_group_code text, crossing_feature_type text, diff --git a/db/tables/observations.sql b/db/tables/observations.sql index 5fd6ab66..958fd341 100644 --- a/db/tables/observations.sql +++ b/db/tables/observations.sql @@ -1,5 +1,3 @@ -DROP TABLE IF EXISTS bcfishpass.observations cascade; - CREATE TABLE bcfishpass.observations ( fish_obsrvtn_event_id bigint primary key, @@ -16,11 +14,11 @@ CREATE TABLE bcfishpass.observations ); -- index -create index if not exists obsrvtn_linear_feature_id_idx on bcfishpass.observations (linear_feature_id); -create index if not exists obsrvtn_blue_line_key_idx on bcfishpass.observations (blue_line_key); -create index if not exists obsrvtn_watershed_group_code_idx on bcfishpass.observations (watershed_group_code); -create index if not exists obsrvtn_wsc_gidx on bcfishpass.observations using gist (wscode_ltree); -create index if not exists obsrvtn_wsc_bidx on bcfishpass.observations using btree (wscode_ltree); -create index if not exists obsrvtn_lc_gidx on bcfishpass.observations using gist (localcode_ltree); -create index if not exists obsrvtn_lc_bidx on bcfishpass.observations using btree (localcode_ltree); -create index if not exists obsrvtn_geom_idx on bcfishpass.observations using gist (geom); \ No newline at end of file +create index obsrvtn_linear_feature_id_idx on bcfishpass.observations (linear_feature_id); +create index obsrvtn_blue_line_key_idx on bcfishpass.observations (blue_line_key); +create index obsrvtn_watershed_group_code_idx on bcfishpass.observations (watershed_group_code); +create index obsrvtn_wsc_gidx on bcfishpass.observations using gist (wscode_ltree); +create index obsrvtn_wsc_bidx on bcfishpass.observations using btree (wscode_ltree); +create index obsrvtn_lc_gidx on bcfishpass.observations using gist (localcode_ltree); +create index obsrvtn_lc_bidx on bcfishpass.observations using btree (localcode_ltree); +create index obsrvtn_geom_idx on bcfishpass.observations using gist (geom); \ No newline at end of file diff --git a/db/tables/parameters.sql b/db/tables/parameters.sql index 89e2ddf6..bd75501f 100644 --- a/db/tables/parameters.sql +++ b/db/tables/parameters.sql @@ -4,7 +4,6 @@ -- method -- specify which watersheds to include, which habitat model to use -- -------------- -drop table if exists bcfishpass.parameters_habitat_method cascade; create table bcfishpass.parameters_habitat_method ( watershed_group_code character varying(4), @@ -15,7 +14,6 @@ create table bcfishpass.parameters_habitat_method -- thresholds -- define various spawning/rearing thresholds for species to be modelled -- -------------- -drop table if exists bcfishpass.parameters_habitat_thresholds cascade; create table bcfishpass.parameters_habitat_thresholds ( species_code text, spawn_gradient_max numeric, @@ -31,10 +29,9 @@ create table bcfishpass.parameters_habitat_thresholds ( rear_lake_ha_min integer ); - -- -------------- -- list of watershed groups to process in access model/crossings --- defaults to all -- -------------- -drop table if exists bcfishpass.watershed_groups_access; -create table bcfishpass.watershed_groups_access as select watershed_group_code from whse_basemapping.fwa_watershed_groups_poly; \ No newline at end of file +create table bcfishpass.watershed_groups_access ( + watershed_group_code character varying(4) +); \ No newline at end of file diff --git a/db/tables/streams.sql b/db/tables/streams.sql index 1370046f..3580e3e0 100644 --- a/db/tables/streams.sql +++ b/db/tables/streams.sql @@ -5,9 +5,6 @@ -- unique segmented stream id is created by combining blkey and measure -- (with measure rounded to nearest mm, because some source stream lines are really short) -- -------------- - -drop table if exists bcfishpass.streams cascade; - create table bcfishpass.streams ( segmented_stream_id text diff --git a/db/tables/streams_upstr_dnstr.sql b/db/tables/streams_upstr_dnstr.sql index d37433aa..19efeee7 100644 --- a/db/tables/streams_upstr_dnstr.sql +++ b/db/tables/streams_upstr_dnstr.sql @@ -2,7 +2,6 @@ -- Create tables tracking features downstream of streams (and upstream observations) -- -drop table if exists bcfishpass.streams_dnstr_barriers cascade; create table bcfishpass.streams_dnstr_barriers ( segmented_stream_id text primary key, barriers_anthropogenic_dnstr text[], @@ -17,27 +16,23 @@ create table bcfishpass.streams_dnstr_barriers ( ); -- all crossings dnstr, not just barriers -drop table if exists bcfishpass.streams_dnstr_crossings cascade; create table bcfishpass.streams_dnstr_crossings ( segmented_stream_id text primary key, crossings_dnstr text[] ); -- remediations/barriers downstream (for mapping barrier type of next downstream barrier) -drop table if exists bcfishpass.streams_dnstr_barriers_remediations cascade; create table bcfishpass.streams_dnstr_barriers_remediations ( segmented_stream_id text primary key, remediations_barriers_dnstr text[] ); -- observations (for convenience in the field and reporting, not an input to individual models) -drop table if exists bcfishpass.streams_dnstr_species cascade; create table bcfishpass.streams_dnstr_species ( segmented_stream_id text primary key, species_codes_dnstr text[] ); -drop table if exists bcfishpass.streams_upstr_observations cascade; create table bcfishpass.streams_upstr_observations ( segmented_stream_id text primary key, obsrvtn_event_upstr bigint[], diff --git a/db/tables/transport_line.sql b/db/tables/transport_line.sql new file mode 100644 index 00000000..a8418755 --- /dev/null +++ b/db/tables/transport_line.sql @@ -0,0 +1,132 @@ +CREATE TABLE whse_basemapping.transport_line_divided_code ( + transport_line_divided_code character varying(1) PRIMARY KEY, + description character varying(20) NOT NULL, + create_integration_session_id integer NOT NULL, + create_integration_date timestamp with time zone, + modify_integration_session_id integer NOT NULL, + modify_integration_date timestamp with time zone +); + +CREATE TABLE whse_basemapping.transport_line_structure_code ( + transport_line_structure_code character varying(1) PRIMARY KEY, + description character varying(20) NOT NULL, + create_integration_session_id integer NOT NULL, + create_integration_date timestamp with time zone, + modify_integration_session_id integer NOT NULL, + modify_integration_date timestamp with time zone +); + +CREATE TABLE whse_basemapping.transport_line_surface_code ( + transport_line_surface_code character varying(1) PRIMARY KEY, + description character varying(20) NOT NULL, + create_integration_session_id integer NOT NULL, + create_integration_date timestamp with time zone, + modify_integration_session_id integer NOT NULL, + modify_integration_date timestamp with time zone +); + +CREATE TABLE whse_basemapping.transport_line_type_code ( + transport_line_type_code character varying(3) PRIMARY KEY, + description character varying(30) NOT NULL, + demographic_ind character varying(1) NOT NULL, + create_integration_session_id integer NOT NULL, + create_integration_date timestamp with time zone, + modify_integration_session_id integer NOT NULL, + modify_integration_date timestamp with time zone, + road_class character varying(12) NOT NULL +); + +CREATE TABLE whse_basemapping.transport_line ( + transport_line_id SERIAL PRIMARY KEY, + create_integration_session_id integer NOT NULL, + create_integration_date timestamp with time zone, + modify_integration_session_id integer NOT NULL, + modify_integration_date timestamp with time zone, + create_partner_org_id integer NOT NULL, + create_partner_org character varying(110), + modify_partner_org_id integer NOT NULL, + modify_partner_org character varying(110), + custodian_partner_org_id integer, + custodian_partner_org character varying(110), + data_capture_method_code character varying(30) NOT NULL, + z_value_derived_ind character varying(1), + capture_date timestamp with time zone, + deactivation_date timestamp with time zone, + transport_line_type_code character varying(3) NOT NULL, + transport_line_surface_code character varying(1) NOT NULL, + transport_line_divided_code character varying(1) NOT NULL, + travel_direction_code character varying(1) NOT NULL, + transport_line_structure_code character varying(1), + speed_limit smallint NOT NULL, + left_number_of_lanes smallint NOT NULL, + right_number_of_lanes smallint NOT NULL, + total_number_of_lanes smallint NOT NULL, + under_construction_ind character varying(1) NOT NULL, + virtual_ind character varying(1) NOT NULL, + disaster_route_ind character varying(1) NOT NULL, + truck_route_ind character varying(1) NOT NULL, + left_locality_id integer, + left_locality character varying(50), + right_locality_id integer, + right_locality character varying(50), + left_regional_district_id character varying(5), + right_regional_district_id character varying(5), + structured_name_1_id integer, + structured_name_1 character varying(100), + structured_name_2_id integer, + structured_name_2 character varying(100), + structured_name_3_id integer, + structured_name_3 character varying(100), + structured_name_4_id integer, + structured_name_4 character varying(100), + structured_name_5_id integer, + structured_name_5 character varying(100), + structured_name_6_id integer, + structured_name_6 character varying(100), + structured_name_7_id integer, + structured_name_7 character varying(100), + highway_route_1 character varying(5), + highway_route_2 character varying(5), + highway_route_3 character varying(5), + highway_exit_number character varying(5), + industry_name_1 character varying(255), + industry_name_2 character varying(255), + industry_name_3 character varying(255), + single_house_number integer, + left_house_num_scheme_code character varying(1) NOT NULL, + from_left_house_number integer, + to_left_house_number integer, + right_house_num_scheme_code character varying(1) NOT NULL, + from_right_house_number integer, + to_right_house_number integer, + lane_restriction_code character varying(1), + access_restriction_code character varying(2) NOT NULL, + from_traffic_impactor_code character varying(1), + to_traffic_impactor_code character varying(1), + from_left_turn_time_code character varying(8), + from_centre_turn_time_code character varying(8), + from_right_turn_time_code character varying(8), + to_left_turn_time_code character varying(8), + to_centre_turn_time_code character varying(8), + to_right_turn_time_code character varying(8), + from_vehicle_max_weight_kg integer, + to_vehicle_max_weight_kg integer, + from_vehicle_max_width_metre double precision, + to_vehicle_max_width_metre double precision, + from_vehicle_max_height_metre double precision, + to_vehicle_max_height_metre double precision, + ministry_of_transport_id integer, + ministry_of_transport_name character varying(255), + integration_notes character varying(4000), + excluded_rules character varying(4000), + demographic_ind character varying(1) NOT NULL, + extended_data character varying, + ministry_of_transport_data character varying, + from_navigation_rules character varying, + along_navigation_rules character varying, + to_navigation_rules character varying, + from_transport_node_point_id integer, + to_transport_node_point_id integer, + geom geometry(MultiLineStringZ,3005) +); +CREATE INDEX transport_line_geom_geom_idx ON whse_basemapping.transport_line USING GIST (geom); \ No newline at end of file diff --git a/db/tables/user.sql b/db/tables/user.sql index 15fb4f27..84f58434 100644 --- a/db/tables/user.sql +++ b/db/tables/user.sql @@ -7,7 +7,6 @@ -- (via smallest distance or matched name) does not match correctly -- ***PSCIS crossings present in the lookup with no stream/modelled crossing do not get matched to a stream*** -- -------------- -drop table if exists bcfishpass.pscis_modelledcrossings_streams_xref cascade; create table bcfishpass.pscis_modelledcrossings_streams_xref ( stream_crossing_id integer PRIMARY KEY, @@ -26,7 +25,6 @@ create table bcfishpass.pscis_modelledcrossings_streams_xref -- Note that we want simple integer unique ids for all anthropogenic barriers that remain constant. -- So do not autogenerate, maintain them in the csv manually for now -- -------------- -drop table if exists bcfishpass.user_barriers_anthropogenic cascade; create table bcfishpass.user_barriers_anthropogenic ( user_barrier_anthropogenic_id integer PRIMARY KEY, @@ -48,7 +46,6 @@ create table bcfishpass.user_barriers_anthropogenic -- -- User added Non-falls definite barrers (exclusions, misc, other) -- -------------- -drop table if exists bcfishpass.user_barriers_definite cascade; create table bcfishpass.user_barriers_definite ( barrier_type text, @@ -69,7 +66,6 @@ create table bcfishpass.user_barriers_definite -- -- Modify barrier status of natural features (waterfalls, gradient barriers, subsurface flow) -- -------------- -drop table if exists bcfishpass.user_barriers_definite_control cascade; create table bcfishpass.user_barriers_definite_control ( blue_line_key integer, @@ -89,7 +85,6 @@ create table bcfishpass.user_barriers_definite_control -- -- ids of cabd dams to exclude -- -------------- -drop table if exists bcfishpass.user_cabd_dams_exclusions; create table bcfishpass.user_cabd_dams_exclusions ( cabd_id text, reviewer_name text, @@ -105,7 +100,6 @@ create table bcfishpass.user_cabd_dams_exclusions ( -- additional falls, from various sources -- (not grouped in with user_barriers_definite because tracking non-barrier falls is useful) -- -------------- -drop table if exists bcfishpass.user_falls cascade; create table bcfishpass.user_falls ( falls_name text, @@ -127,7 +121,6 @@ create table bcfishpass.user_falls -- -- designate stream segments as known rearing/spawning -- -------------- -drop table if exists bcfishpass.user_habitat_classification cascade; create table bcfishpass.user_habitat_classification ( blue_line_key integer, @@ -151,7 +144,6 @@ create table bcfishpass.user_habitat_classification -- user defined override for modelled crossings that are either OBS or non-existent -- note that this table uses modelled_crossing_id as identifier rather than blkey/measure -- -------------- -drop table if exists bcfishpass.user_modelled_crossing_fixes cascade; create table bcfishpass.user_modelled_crossing_fixes ( modelled_crossing_id integer, @@ -173,7 +165,6 @@ create index on bcfishpass.user_modelled_crossing_fixes (modelled_crossing_id); -- -- manual override of PSCIS status -- -------------- -drop table if exists bcfishpass.user_pscis_barrier_status cascade; create table bcfishpass.user_pscis_barrier_status ( stream_crossing_id integer PRIMARY KEY, @@ -191,7 +182,6 @@ create table bcfishpass.user_pscis_barrier_status -- presence/absence of target species within all BC watershed groups -- SOURCE - CWF WCRP project area scoping (2020) -- -------------- -drop table if exists bcfishpass.wsg_species_presence cascade; create table bcfishpass.wsg_species_presence ( watershed_group_code varchar(4), @@ -217,7 +207,6 @@ create table bcfishpass.wsg_species_presence -- include waterbody_poly_id in this table if a given lake is/was known to support sockeye -- source DFO conservation units via PSF -- -------------------- -drop table if exists bcfishpass.dfo_known_sockeye_lakes cascade; create table bcfishpass.dfo_known_sockeye_lakes ( waterbody_poly_id integer primary key ); diff --git a/db/views/01_dams_vw.sql b/db/views/01_dams_vw.sql index 1aa106b0..25582b9b 100644 --- a/db/views/01_dams_vw.sql +++ b/db/views/01_dams_vw.sql @@ -1,7 +1,4 @@ -- reference CABD dams to FWA stream network - -drop materialized view if exists bcfishpass.dams_vw cascade; - create materialized view bcfishpass.dams_vw as with cabd as ( select @@ -113,7 +110,6 @@ from usa; create unique index on bcfishpass.dams_vw (dam_id); create index on bcfishpass.dams_vw using gist (geom); -drop view if exists bcfishpass.dams_not_matched_to_streams; create view bcfishpass.dams_not_matched_to_streams as select a.cabd_id, diff --git a/db/views/01_streams.sql b/db/views/01_streams.sql index 7270d705..8fec3db7 100644 --- a/db/views/01_streams.sql +++ b/db/views/01_streams.sql @@ -1,6 +1,4 @@ -- access - view of stream data plus downstream barrier info -drop materialized view if exists bcfishpass.streams_access_vw cascade; - create materialized view bcfishpass.streams_access_vw as select s.segmented_stream_id, @@ -79,7 +77,6 @@ left outer join bcfishpass.crossings x on r.remediations_barriers_dnstr[1] = x.a create unique index on bcfishpass.streams_access_vw (segmented_stream_id); -- view of known/observed spawning / rearing locations (from CWF/FISS/PSE) for easy ref -drop materialized view if exists bcfishpass.streams_habitat_known_vw; CREATE materialized view bcfishpass.streams_habitat_known_vw AS WITH manual_habitat_class AS ( @@ -167,7 +164,6 @@ ORDER BY segmented_stream_id; create unique index on bcfishpass.streams_habitat_known_vw (segmented_stream_id); -- combine various modelled habitat tables into single modelled habitat view -drop materialized view if exists bcfishpass.streams_habitat_linear_vw; create materialized view bcfishpass.streams_habitat_linear_vw as select s.segmented_stream_id, @@ -217,9 +213,6 @@ create unique index on bcfishpass.streams_habitat_linear_vw (segmented_stream_id -- INTERMITTENT -- (note - consider adding a non-intermittent code for easier classification?) - -drop materialized view if exists bcfishpass.streams_mapping_code_vw; - create materialized view bcfishpass.streams_mapping_code_vw as with mcbi as ( diff --git a/db/views/02_crossings.sql b/db/views/02_crossings.sql index 7923c565..a3666199 100644 --- a/db/views/02_crossings.sql +++ b/db/views/02_crossings.sql @@ -1,5 +1,4 @@ -- crossing feature type -drop view if exists bcfishpass.crossings_feature_type_vw cascade; create view bcfishpass.crossings_feature_type_vw as select aggregated_crossings_id, @@ -81,8 +80,6 @@ from bcfishpass.crossings; -- counts of anthropogenic barriers upstream per access model -- (for example, number of barriers on steelhead accessible stream upstream of given barrier) -drop materialized view if exists bcfishpass.crossings_upstr_barriers_per_model_vw cascade; - create materialized view bcfishpass.crossings_upstr_barriers_per_model_vw as with access_models as ( @@ -148,42 +145,37 @@ on c.aggregated_crossings_id = bpm.aggregated_crossings_id; create unique index on bcfishpass.crossings_upstr_barriers_per_model_vw (aggregated_crossings_id); --- below datasets are not guaranteed to exist, leave this out for now - ---drop materialized view if exists bcfishpass.crossings_admin; ---create materialized view bcfishpass.crossings_admin; ---SELECT DISTINCT ON (c.aggregated_crossings_id) -- some of the admin areas are not clean/distinct, make sure to select just one --- c.aggregated_crossings_id, --- rd.admin_area_abbreviation as abms_regional_district, --- muni.admin_area_abbreviation as abms_municipality, --- ir.english_name as clab_indian_reserve_name, --- ir.band_name as clab_indian_reserve_band_name, --- np.english_name as clab_national_park_name, --- pp.protected_lands_name as bc_protected_lands_name, --- pmbc.owner_type as pmbc_owner_type, --- nr.region_org_unit_name as adm_nr_region, --- nr.district_name as adm_nr_district ---FROM bcfishpass.crossings c ---LEFT OUTER JOIN whse_legal_admin_boundaries.abms_regional_districts_sp rd ---ON ST_Intersects(c.geom, rd.geom) ---LEFT OUTER JOIN whse_legal_admin_boundaries.abms_municipalities_sp muni ---ON ST_Intersects(c.geom, muni.geom) ---LEFT OUTER JOIN whse_admin_boundaries.adm_indian_reserves_bands_sp ir ---ON ST_Intersects(c.geom, ir.geom) ---LEFT OUTER JOIN whse_admin_boundaries.clab_national_parks np ---ON ST_Intersects(c.geom, np.geom) ---LEFT OUTER JOIN whse_tantalis.ta_park_ecores_pa_svw pp ---ON ST_Intersects(c.geom, pp.geom) ---LEFT OUTER JOIN whse_cadastre.pmbc_parcel_fabric_poly_svw pmbc ---ON ST_Intersects(c.geom, pmbc.geom) ---LEFT OUTER JOIN whse_admin_boundaries.adm_nr_districts_sp nr ---ON ST_Intersects(c.geom, pmbc.geom) ---ORDER BY c.aggregated_crossings_id, rd.admin_area_abbreviation, muni.admin_area_abbreviation, ir.english_name, pp.protected_lands_name, pmbc.owner_type, nr.district_name; +create materialized view bcfishpass.crossings_admin AS +SELECT DISTINCT ON (c.aggregated_crossings_id) -- some of the admin areas are not clean/distinct, make sure to select just one + c.aggregated_crossings_id, + rd.admin_area_abbreviation as abms_regional_district, + muni.admin_area_abbreviation as abms_municipality, + ir.english_name as clab_indian_reserve_name, + ir.band_name as clab_indian_reserve_band_name, + np.english_name as clab_national_park_name, + pp.protected_lands_name as bc_protected_lands_name, + pmbc.owner_type as pmbc_owner_type, + nr.region_org_unit_name as adm_nr_region, + nr.district_name as adm_nr_district +FROM bcfishpass.crossings c +LEFT OUTER JOIN whse_legal_admin_boundaries.abms_regional_districts_sp rd +ON ST_Intersects(c.geom, rd.geom) +LEFT OUTER JOIN whse_legal_admin_boundaries.abms_municipalities_sp muni +ON ST_Intersects(c.geom, muni.geom) +LEFT OUTER JOIN whse_admin_boundaries.adm_indian_reserves_bands_sp ir +ON ST_Intersects(c.geom, ir.geom) +LEFT OUTER JOIN whse_admin_boundaries.clab_national_parks np +ON ST_Intersects(c.geom, np.geom) +LEFT OUTER JOIN whse_tantalis.ta_park_ecores_pa_svw pp +ON ST_Intersects(c.geom, pp.geom) +LEFT OUTER JOIN whse_cadastre.pmbc_parcel_fabric_poly_svw pmbc +ON ST_Intersects(c.geom, pmbc.geom) +LEFT OUTER JOIN whse_admin_boundaries.adm_nr_districts_spg nr +ON ST_Intersects(c.geom, pmbc.geom) +ORDER BY c.aggregated_crossings_id, rd.admin_area_abbreviation, muni.admin_area_abbreviation, ir.english_name, pp.protected_lands_name, pmbc.owner_type, nr.district_name; -- downstream observations ***within the same watershed group*** -drop materialized view if exists bcfishpass.crossings_dnstr_observations_vw cascade; - create materialized view bcfishpass.crossings_dnstr_observations_vw as select aggregated_crossings_id, @@ -214,8 +206,6 @@ create index on bcfishpass.crossings_dnstr_observations_vw (aggregated_crossings -- upstream observations ***within the same watershed group*** -drop materialized view if exists bcfishpass.crossings_upstr_observations_vw cascade; - create materialized view bcfishpass.crossings_upstr_observations_vw as select aggregated_crossings_id, @@ -249,7 +239,6 @@ create index on bcfishpass.crossings_upstr_observations_vw (aggregated_crossings -- final output crossings view - -- join crossings table to streams / access / habitat tables -- and convert array types to text for easier dumps -drop materialized view if exists bcfishpass.crossings_vw cascade; -- cascade FPTWG crossings view if exists create materialized view bcfishpass.crossings_vw as select -- joining to streams based on measure can be error prone due to precision. @@ -499,8 +488,6 @@ create index on bcfishpass.crossings_vw using gist (geom); -- wcrp version of the output crossings view - - -drop materialized view if exists bcfishpass.crossings_wcrp_vw cascade; -- cascade FPTWG crossings view if exists create materialized view bcfishpass.crossings_wcrp_vw as select -- joining to streams based on measure can be error prone due to precision. diff --git a/db/views/03_observations_vw.sql b/db/views/03_observations_vw.sql index e1bcc486..899d883f 100644 --- a/db/views/03_observations_vw.sql +++ b/db/views/03_observations_vw.sql @@ -1,7 +1,5 @@ -- create view of distinct observations for simpler species based queries -drop materialized view if exists bcfishpass.observations_vw cascade; create materialized view bcfishpass.observations_vw as - with unnested as (select unnest(observation_ids) as fish_observation_point_id, diff --git a/db/views/04_falls_vw.sql b/db/views/04_falls_vw.sql index 6e9f7ecb..e330d777 100644 --- a/db/views/04_falls_vw.sql +++ b/db/views/04_falls_vw.sql @@ -1,7 +1,5 @@ -- load CABD falls and any misc (temporary) additions from bcfishpass table -drop materialized view if exists bcfishpass.falls_vw cascade; - create materialized view bcfishpass.falls_vw as with cabd as ( @@ -88,7 +86,6 @@ create unique index on bcfishpass.falls_vw (falls_id); create index on bcfishpass.falls_vw using gist (geom); -- a view of falls that do not get matched to streams -drop view if exists bcfishpass.falls_not_matched_to_streams; create view bcfishpass.falls_not_matched_to_streams as select a.cabd_id, @@ -101,8 +98,6 @@ order by a.cabd_id; -- a view of all falls, with counts of observations upstream, for salmon and steelhead -drop materialized view if exists bcfishpass.falls_upstr_anadromous_vw; - create materialized view bcfishpass.falls_upstr_anadromous_vw as with upstr_sal as ( select diff --git a/db/views/05_streams_spp.sql b/db/views/05_streams_spp.sql new file mode 100644 index 00000000..1d035ea2 --- /dev/null +++ b/db/views/05_streams_spp.sql @@ -0,0 +1,468 @@ +create view bcfishpass.streams_bt_vw as +select + s.segmented_stream_id, + s.linear_feature_id, + s.edge_type, + s.blue_line_key, + s.watershed_key, + s.watershed_group_code, + s.downstream_route_measure, + s.length_metre, + s.waterbody_key, + s.wscode_ltree::text as wscode, + s.localcode_ltree::text as localcode, + s.gnis_name, + s.stream_order, + s.stream_magnitude, + s.gradient, + s.feature_code, + s.upstream_route_measure, + s.upstream_area_ha, + s.map_upstream, + s.channel_width, + s.mad_m3s, + s.stream_order_parent, + s.stream_order_max, + array_to_string(a.barriers_bt_dnstr, ';') as barriers_bt_dnstr, + array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, + array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, + array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, + array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, + array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, + a.obsrvtn_upstr_bt, + a.dam_dnstr_ind, + a.dam_hydro_dnstr_ind, + a.remediated_dnstr_ind, + h.spawning_bt as spawning, + h.rearing_bt as rearing, + hk.spawning_bt as spawning_known, + hk.rearing_bt as rearing_known, + m.mapping_code_bt as mapping_code, + s.geom +from bcfishpass.streams s +left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id +left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id +left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id +left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id +where cardinality(a.barriers_bt_dnstr) = 0; + + +create view bcfishpass.streams_ch_vw as +select + s.segmented_stream_id, + s.linear_feature_id, + s.edge_type, + s.blue_line_key, + s.watershed_key, + s.watershed_group_code, + s.downstream_route_measure, + s.length_metre, + s.waterbody_key, + s.wscode_ltree::text as wscode, + s.localcode_ltree::text as localcode, + s.gnis_name, + s.stream_order, + s.stream_magnitude, + s.gradient, + s.feature_code, + s.upstream_route_measure, + s.upstream_area_ha, + s.map_upstream, + s.channel_width, + s.mad_m3s, + s.stream_order_parent, + s.stream_order_max, + array_to_string(a.barriers_ch_cm_co_pk_sk_dnstr, ';') as barriers_ch_cm_co_pk_sk_dnstr, + array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, + array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, + array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, + array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, + array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, + a.obsrvtn_upstr_ch, + a.dam_dnstr_ind, + a.dam_hydro_dnstr_ind, + a.remediated_dnstr_ind, + h.spawning_ch as spawning, + h.rearing_ch as rearing, + hk.spawning_ch as spawning_known, + hk.rearing_ch as rearing_known, + m.mapping_code_ch as mapping_code, + s.geom +from bcfishpass.streams s +left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id +left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id +left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id +left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id +where cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0; + + +create view bcfishpass.streams_cm_vw as +select + s.segmented_stream_id, + s.linear_feature_id, + s.edge_type, + s.blue_line_key, + s.watershed_key, + s.watershed_group_code, + s.downstream_route_measure, + s.length_metre, + s.waterbody_key, + s.wscode_ltree::text as wscode, + s.localcode_ltree::text as localcode, + s.gnis_name, + s.stream_order, + s.stream_magnitude, + s.gradient, + s.feature_code, + s.upstream_route_measure, + s.upstream_area_ha, + s.map_upstream, + s.channel_width, + s.mad_m3s, + s.stream_order_parent, + s.stream_order_max, + array_to_string(a.barriers_ch_cm_co_pk_sk_dnstr, ';') as barriers_ch_cm_co_pk_sk_dnstr, + array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, + array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, + array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, + array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, + array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, + a.obsrvtn_upstr_cm, + a.dam_dnstr_ind, + a.dam_hydro_dnstr_ind, + a.remediated_dnstr_ind, + h.spawning_cm as spawning, + null as rearing, + hk.spawning_ch as spawning_known, + null as rearing_known, + m.mapping_code_cm as mapping_code, + s.geom +from bcfishpass.streams s +left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id +left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id +left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id +left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id +where cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0; + + +create view bcfishpass.streams_co_vw as +select + s.segmented_stream_id, + s.linear_feature_id, + s.edge_type, + s.blue_line_key, + s.watershed_key, + s.watershed_group_code, + s.downstream_route_measure, + s.length_metre, + s.waterbody_key, + s.wscode_ltree::text as wscode, + s.localcode_ltree::text as localcode, + s.gnis_name, + s.stream_order, + s.stream_magnitude, + s.gradient, + s.feature_code, + s.upstream_route_measure, + s.upstream_area_ha, + s.map_upstream, + s.channel_width, + s.mad_m3s, + s.stream_order_parent, + s.stream_order_max, + array_to_string(a.barriers_ch_cm_co_pk_sk_dnstr, ';') as barriers_ch_cm_co_pk_sk_dnstr, + array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, + array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, + array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, + array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, + array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, + a.obsrvtn_upstr_co, + a.dam_dnstr_ind, + a.dam_hydro_dnstr_ind, + a.remediated_dnstr_ind, + h.spawning_co as spawning, + h.rearing_co as rearing, + hk.spawning_co as spawning_known, + hk.rearing_co as rearing_known, + m.mapping_code_co as mapping_code, + geom +from bcfishpass.streams s +left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id +left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id +left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id +left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id +where cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0; + +create view bcfishpass.streams_pk_vw as +select + s.segmented_stream_id, + s.linear_feature_id, + s.edge_type, + s.blue_line_key, + s.watershed_key, + s.watershed_group_code, + s.downstream_route_measure, + s.length_metre, + s.waterbody_key, + s.wscode_ltree::text as wscode, + s.localcode_ltree::text as localcode, + s.gnis_name, + s.stream_order, + s.stream_magnitude, + s.gradient, + s.feature_code, + s.upstream_route_measure, + s.upstream_area_ha, + s.map_upstream, + s.channel_width, + s.mad_m3s, + s.stream_order_parent, + s.stream_order_max, + array_to_string(a.barriers_ch_cm_co_pk_sk_dnstr, ';') as barriers_ch_cm_co_pk_sk_dnstr, + array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, + array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, + array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, + array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, + array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, + a.obsrvtn_upstr_pk, + a.dam_dnstr_ind, + a.dam_hydro_dnstr_ind, + a.remediated_dnstr_ind, + h.spawning_pk as spawning, + null as rearing, + hk.spawning_pk as spawning_known, + null as rearing_known, + m.mapping_code_pk as mapping_code, + s.geom +from bcfishpass.streams s +left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id +left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id +left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id +left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id +where cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0; + +create view bcfishpass.streams_salmon_vw as +select + s.segmented_stream_id, + s.linear_feature_id, + s.edge_type, + s.blue_line_key, + s.watershed_key, + s.watershed_group_code, + s.downstream_route_measure, + s.length_metre, + s.waterbody_key, + s.wscode_ltree::text as wscode, + s.localcode_ltree::text as localcode, + s.gnis_name, + s.stream_order, + s.stream_magnitude, + s.gradient, + s.feature_code, + s.upstream_route_measure, + s.upstream_area_ha, + s.map_upstream, + s.channel_width, + s.mad_m3s, + s.stream_order_parent, + s.stream_order_max, + array_to_string(a.barriers_ch_cm_co_pk_sk_dnstr, ';') as barriers_ch_cm_co_pk_sk_dnstr, + array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, + array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, + array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, + array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, + array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, + a.obsrvtn_upstr_salmon, + a.dam_dnstr_ind, + a.dam_hydro_dnstr_ind, + a.remediated_dnstr_ind, + -- potential spawning + case + when + h.spawning_ch is true or + h.spawning_cm is true or + h.spawning_co is true or + h.spawning_pk is true or + h.spawning_sk is true + then true + end as spawning, + -- potential rearing (and not spawning) + case + when + h.rearing_ch is true or + h.rearing_co is true or + h.rearing_sk is true + then true + end as rearing, + -- known spawning + case + when + hk.spawning_ch is true or + hk.spawning_cm is true or + hk.spawning_co is true or + hk.spawning_pk is true or + hk.spawning_sk is true + then true + end as spawning_known, + -- known rearing + case + when + hk.rearing_ch is true or + hk.rearing_co is true or + hk.rearing_sk is true + then true + end as rearing_known, + m.mapping_code_salmon as mapping_code, + s.geom +from bcfishpass.streams s +left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id +left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id +left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id +left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id +where cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0; + +create view bcfishpass.streams_sk_vw as +select + s.segmented_stream_id, + s.linear_feature_id, + s.edge_type, + s.blue_line_key, + s.watershed_key, + s.watershed_group_code, + s.downstream_route_measure, + s.length_metre, + s.waterbody_key, + s.wscode_ltree::text as wscode, + s.localcode_ltree::text as localcode, + s.gnis_name, + s.stream_order, + s.stream_magnitude, + s.gradient, + s.feature_code, + s.upstream_route_measure, + s.upstream_area_ha, + s.map_upstream, + s.channel_width, + s.mad_m3s, + s.stream_order_parent, + s.stream_order_max, + array_to_string(a.barriers_ch_cm_co_pk_sk_dnstr, ';') as barriers_ch_cm_co_pk_sk_dnstr, + array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, + array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, + array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, + array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, + array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, + a.obsrvtn_upstr_sk, + a.dam_dnstr_ind, + a.dam_hydro_dnstr_ind, + a.remediated_dnstr_ind, + h.spawning_sk as spawning, + h.rearing_sk as rearing, + hk.spawning_sk as spawning_known, + hk.rearing_sk as rearing_known, + m.mapping_code_sk as mapping_code, + s.geom +from bcfishpass.streams s +left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id +left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id +left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id +left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id +where cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0; + + +create view bcfishpass.streams_st_vw as +select + s.segmented_stream_id, + s.linear_feature_id, + s.edge_type, + s.blue_line_key, + s.watershed_key, + s.watershed_group_code, + s.downstream_route_measure, + s.length_metre, + s.waterbody_key, + s.wscode_ltree::text as wscode, + s.localcode_ltree::text as localcode, + s.gnis_name, + s.stream_order, + s.stream_magnitude, + s.gradient, + s.feature_code, + s.upstream_route_measure, + s.upstream_area_ha, + s.map_upstream, + s.channel_width, + s.mad_m3s, + s.stream_order_parent, + s.stream_order_max, + array_to_string(a.barriers_st_dnstr, ';') as barriers_st_dnstr, + array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, + array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, + array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, + array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, + array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, + a.obsrvtn_upstr_st, + a.dam_dnstr_ind, + a.dam_hydro_dnstr_ind, + a.remediated_dnstr_ind, + h.spawning_st as spawning, + h.rearing_st as rearing, + hk.spawning_st as spawning_known, + hk.rearing_st as rearing_known, + m.mapping_code_st as mapping_code, + s.geom +from bcfishpass.streams s +left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id +left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id +left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id +left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id +where cardinality(a.barriers_st_dnstr) = 0; + + +create view bcfishpass.streams_wct_vw as +select + s.segmented_stream_id, + s.linear_feature_id, + s.edge_type, + s.blue_line_key, + s.watershed_key, + s.watershed_group_code, + s.downstream_route_measure, + s.length_metre, + s.waterbody_key, + s.wscode_ltree::text as wscode, + s.localcode_ltree::text as localcode, + s.gnis_name, + s.stream_order, + s.stream_magnitude, + s.gradient, + s.feature_code, + s.upstream_route_measure, + s.upstream_area_ha, + s.map_upstream, + s.channel_width, + s.mad_m3s, + s.stream_order_parent, + s.stream_order_max, + array_to_string(a.barriers_wct_dnstr, ';') as barriers_wct_dnstr, + array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, + array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, + array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, + array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, + array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, + a.obsrvtn_upstr_wct, + a.dam_dnstr_ind, + a.dam_hydro_dnstr_ind, + a.remediated_dnstr_ind, + h.spawning_wct as spawning, + h.rearing_wct as rearing, + hk.spawning_wct as spawning_known, + hk.rearing_wct as rearing_known, + m.mapping_code_wct as mapping_code, + s.geom +from bcfishpass.streams s +left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id +left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id +left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id +left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id +where cardinality(a.barriers_wct_dnstr) = 0; \ No newline at end of file diff --git a/db/views/11_streams_bt_vw.sql b/db/views/11_streams_bt_vw.sql deleted file mode 100644 index 794fb464..00000000 --- a/db/views/11_streams_bt_vw.sql +++ /dev/null @@ -1,49 +0,0 @@ -drop view if exists bcfishpass.streams_bt_vw cascade; - -create view bcfishpass.streams_bt_vw as -select - s.segmented_stream_id, - s.linear_feature_id, - s.edge_type, - s.blue_line_key, - s.watershed_key, - s.watershed_group_code, - s.downstream_route_measure, - s.length_metre, - s.waterbody_key, - s.wscode_ltree::text as wscode, - s.localcode_ltree::text as localcode, - s.gnis_name, - s.stream_order, - s.stream_magnitude, - s.gradient, - s.feature_code, - s.upstream_route_measure, - s.upstream_area_ha, - s.map_upstream, - s.channel_width, - s.mad_m3s, - s.stream_order_parent, - s.stream_order_max, - array_to_string(a.barriers_bt_dnstr, ';') as barriers_bt_dnstr, - array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, - array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, - array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, - array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, - array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, - a.obsrvtn_upstr_bt, - a.dam_dnstr_ind, - a.dam_hydro_dnstr_ind, - a.remediated_dnstr_ind, - h.spawning_bt as spawning, - h.rearing_bt as rearing, - hk.spawning_bt as spawning_known, - hk.rearing_bt as rearing_known, - m.mapping_code_bt as mapping_code, - s.geom -from bcfishpass.streams s -left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id -left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id -left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id -left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id -where cardinality(a.barriers_bt_dnstr) = 0; \ No newline at end of file diff --git a/db/views/12_streams_ch_vw.sql b/db/views/12_streams_ch_vw.sql deleted file mode 100644 index 3b92b5b8..00000000 --- a/db/views/12_streams_ch_vw.sql +++ /dev/null @@ -1,49 +0,0 @@ -drop view if exists bcfishpass.streams_ch_vw cascade; - -create view bcfishpass.streams_ch_vw as -select - s.segmented_stream_id, - s.linear_feature_id, - s.edge_type, - s.blue_line_key, - s.watershed_key, - s.watershed_group_code, - s.downstream_route_measure, - s.length_metre, - s.waterbody_key, - s.wscode_ltree::text as wscode, - s.localcode_ltree::text as localcode, - s.gnis_name, - s.stream_order, - s.stream_magnitude, - s.gradient, - s.feature_code, - s.upstream_route_measure, - s.upstream_area_ha, - s.map_upstream, - s.channel_width, - s.mad_m3s, - s.stream_order_parent, - s.stream_order_max, - array_to_string(a.barriers_ch_cm_co_pk_sk_dnstr, ';') as barriers_ch_cm_co_pk_sk_dnstr, - array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, - array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, - array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, - array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, - array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, - a.obsrvtn_upstr_ch, - a.dam_dnstr_ind, - a.dam_hydro_dnstr_ind, - a.remediated_dnstr_ind, - h.spawning_ch as spawning, - h.rearing_ch as rearing, - hk.spawning_ch as spawning_known, - hk.rearing_ch as rearing_known, - m.mapping_code_ch as mapping_code, - s.geom -from bcfishpass.streams s -left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id -left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id -left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id -left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id -where cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0; diff --git a/db/views/13_streams_cm_vw.sql b/db/views/13_streams_cm_vw.sql deleted file mode 100644 index 45a07ea2..00000000 --- a/db/views/13_streams_cm_vw.sql +++ /dev/null @@ -1,49 +0,0 @@ -drop view if exists bcfishpass.streams_cm_vw cascade; - -create view bcfishpass.streams_cm_vw as -select - s.segmented_stream_id, - s.linear_feature_id, - s.edge_type, - s.blue_line_key, - s.watershed_key, - s.watershed_group_code, - s.downstream_route_measure, - s.length_metre, - s.waterbody_key, - s.wscode_ltree::text as wscode, - s.localcode_ltree::text as localcode, - s.gnis_name, - s.stream_order, - s.stream_magnitude, - s.gradient, - s.feature_code, - s.upstream_route_measure, - s.upstream_area_ha, - s.map_upstream, - s.channel_width, - s.mad_m3s, - s.stream_order_parent, - s.stream_order_max, - array_to_string(a.barriers_ch_cm_co_pk_sk_dnstr, ';') as barriers_ch_cm_co_pk_sk_dnstr, - array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, - array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, - array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, - array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, - array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, - a.obsrvtn_upstr_cm, - a.dam_dnstr_ind, - a.dam_hydro_dnstr_ind, - a.remediated_dnstr_ind, - h.spawning_cm as spawning, - null as rearing, - hk.spawning_ch as spawning_known, - null as rearing_known, - m.mapping_code_cm as mapping_code, - s.geom -from bcfishpass.streams s -left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id -left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id -left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id -left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id -where cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0; diff --git a/db/views/14_streams_co_vw.sql b/db/views/14_streams_co_vw.sql deleted file mode 100644 index 40f7c67b..00000000 --- a/db/views/14_streams_co_vw.sql +++ /dev/null @@ -1,49 +0,0 @@ -drop view if exists bcfishpass.streams_co_vw cascade; - -create view bcfishpass.streams_co_vw as -select - s.segmented_stream_id, - s.linear_feature_id, - s.edge_type, - s.blue_line_key, - s.watershed_key, - s.watershed_group_code, - s.downstream_route_measure, - s.length_metre, - s.waterbody_key, - s.wscode_ltree::text as wscode, - s.localcode_ltree::text as localcode, - s.gnis_name, - s.stream_order, - s.stream_magnitude, - s.gradient, - s.feature_code, - s.upstream_route_measure, - s.upstream_area_ha, - s.map_upstream, - s.channel_width, - s.mad_m3s, - s.stream_order_parent, - s.stream_order_max, - array_to_string(a.barriers_ch_cm_co_pk_sk_dnstr, ';') as barriers_ch_cm_co_pk_sk_dnstr, - array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, - array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, - array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, - array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, - array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, - a.obsrvtn_upstr_co, - a.dam_dnstr_ind, - a.dam_hydro_dnstr_ind, - a.remediated_dnstr_ind, - h.spawning_co as spawning, - h.rearing_co as rearing, - hk.spawning_co as spawning_known, - hk.rearing_co as rearing_known, - m.mapping_code_co as mapping_code, - geom -from bcfishpass.streams s -left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id -left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id -left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id -left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id -where cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0; \ No newline at end of file diff --git a/db/views/15_streams_pk_vw.sql b/db/views/15_streams_pk_vw.sql deleted file mode 100644 index 785151fd..00000000 --- a/db/views/15_streams_pk_vw.sql +++ /dev/null @@ -1,49 +0,0 @@ -drop view if exists bcfishpass.streams_pk_vw cascade; - -create view bcfishpass.streams_pk_vw as -select - s.segmented_stream_id, - s.linear_feature_id, - s.edge_type, - s.blue_line_key, - s.watershed_key, - s.watershed_group_code, - s.downstream_route_measure, - s.length_metre, - s.waterbody_key, - s.wscode_ltree::text as wscode, - s.localcode_ltree::text as localcode, - s.gnis_name, - s.stream_order, - s.stream_magnitude, - s.gradient, - s.feature_code, - s.upstream_route_measure, - s.upstream_area_ha, - s.map_upstream, - s.channel_width, - s.mad_m3s, - s.stream_order_parent, - s.stream_order_max, - array_to_string(a.barriers_ch_cm_co_pk_sk_dnstr, ';') as barriers_ch_cm_co_pk_sk_dnstr, - array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, - array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, - array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, - array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, - array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, - a.obsrvtn_upstr_pk, - a.dam_dnstr_ind, - a.dam_hydro_dnstr_ind, - a.remediated_dnstr_ind, - h.spawning_pk as spawning, - null as rearing, - hk.spawning_pk as spawning_known, - null as rearing_known, - m.mapping_code_pk as mapping_code, - s.geom -from bcfishpass.streams s -left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id -left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id -left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id -left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id -where cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0; \ No newline at end of file diff --git a/db/views/16_streams_salmon_vw.sql b/db/views/16_streams_salmon_vw.sql deleted file mode 100644 index cc955431..00000000 --- a/db/views/16_streams_salmon_vw.sql +++ /dev/null @@ -1,81 +0,0 @@ -drop view if exists bcfishpass.streams_salmon_vw cascade; - -create view bcfishpass.streams_salmon_vw as -select - s.segmented_stream_id, - s.linear_feature_id, - s.edge_type, - s.blue_line_key, - s.watershed_key, - s.watershed_group_code, - s.downstream_route_measure, - s.length_metre, - s.waterbody_key, - s.wscode_ltree::text as wscode, - s.localcode_ltree::text as localcode, - s.gnis_name, - s.stream_order, - s.stream_magnitude, - s.gradient, - s.feature_code, - s.upstream_route_measure, - s.upstream_area_ha, - s.map_upstream, - s.channel_width, - s.mad_m3s, - s.stream_order_parent, - s.stream_order_max, - array_to_string(a.barriers_ch_cm_co_pk_sk_dnstr, ';') as barriers_ch_cm_co_pk_sk_dnstr, - array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, - array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, - array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, - array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, - array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, - a.obsrvtn_upstr_salmon, - a.dam_dnstr_ind, - a.dam_hydro_dnstr_ind, - a.remediated_dnstr_ind, - -- potential spawning - case - when - h.spawning_ch is true or - h.spawning_cm is true or - h.spawning_co is true or - h.spawning_pk is true or - h.spawning_sk is true - then true - end as spawning, - -- potential rearing (and not spawning) - case - when - h.rearing_ch is true or - h.rearing_co is true or - h.rearing_sk is true - then true - end as rearing, - -- known spawning - case - when - hk.spawning_ch is true or - hk.spawning_cm is true or - hk.spawning_co is true or - hk.spawning_pk is true or - hk.spawning_sk is true - then true - end as spawning_known, - -- known rearing - case - when - hk.rearing_ch is true or - hk.rearing_co is true or - hk.rearing_sk is true - then true - end as rearing_known, - m.mapping_code_salmon as mapping_code, - s.geom -from bcfishpass.streams s -left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id -left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id -left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id -left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id -where cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0; \ No newline at end of file diff --git a/db/views/17_streams_sk_vw.sql b/db/views/17_streams_sk_vw.sql deleted file mode 100644 index 1255d94c..00000000 --- a/db/views/17_streams_sk_vw.sql +++ /dev/null @@ -1,49 +0,0 @@ -drop view if exists bcfishpass.streams_sk_vw cascade; - -create view bcfishpass.streams_sk_vw as -select - s.segmented_stream_id, - s.linear_feature_id, - s.edge_type, - s.blue_line_key, - s.watershed_key, - s.watershed_group_code, - s.downstream_route_measure, - s.length_metre, - s.waterbody_key, - s.wscode_ltree::text as wscode, - s.localcode_ltree::text as localcode, - s.gnis_name, - s.stream_order, - s.stream_magnitude, - s.gradient, - s.feature_code, - s.upstream_route_measure, - s.upstream_area_ha, - s.map_upstream, - s.channel_width, - s.mad_m3s, - s.stream_order_parent, - s.stream_order_max, - array_to_string(a.barriers_ch_cm_co_pk_sk_dnstr, ';') as barriers_ch_cm_co_pk_sk_dnstr, - array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, - array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, - array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, - array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, - array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, - a.obsrvtn_upstr_sk, - a.dam_dnstr_ind, - a.dam_hydro_dnstr_ind, - a.remediated_dnstr_ind, - h.spawning_sk as spawning, - h.rearing_sk as rearing, - hk.spawning_sk as spawning_known, - hk.rearing_sk as rearing_known, - m.mapping_code_sk as mapping_code, - s.geom -from bcfishpass.streams s -left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id -left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id -left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id -left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id -where cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0; \ No newline at end of file diff --git a/db/views/18_streams_st_vw.sql b/db/views/18_streams_st_vw.sql deleted file mode 100644 index 21f181f4..00000000 --- a/db/views/18_streams_st_vw.sql +++ /dev/null @@ -1,49 +0,0 @@ -drop view if exists bcfishpass.streams_st_vw cascade; - -create view bcfishpass.streams_st_vw as -select - s.segmented_stream_id, - s.linear_feature_id, - s.edge_type, - s.blue_line_key, - s.watershed_key, - s.watershed_group_code, - s.downstream_route_measure, - s.length_metre, - s.waterbody_key, - s.wscode_ltree::text as wscode, - s.localcode_ltree::text as localcode, - s.gnis_name, - s.stream_order, - s.stream_magnitude, - s.gradient, - s.feature_code, - s.upstream_route_measure, - s.upstream_area_ha, - s.map_upstream, - s.channel_width, - s.mad_m3s, - s.stream_order_parent, - s.stream_order_max, - array_to_string(a.barriers_st_dnstr, ';') as barriers_st_dnstr, - array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, - array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, - array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, - array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, - array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, - a.obsrvtn_upstr_st, - a.dam_dnstr_ind, - a.dam_hydro_dnstr_ind, - a.remediated_dnstr_ind, - h.spawning_st as spawning, - h.rearing_st as rearing, - hk.spawning_st as spawning_known, - hk.rearing_st as rearing_known, - m.mapping_code_st as mapping_code, - s.geom -from bcfishpass.streams s -left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id -left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id -left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id -left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id -where cardinality(a.barriers_st_dnstr) = 0; \ No newline at end of file diff --git a/db/views/19_streams_wct_vw.sql b/db/views/19_streams_wct_vw.sql deleted file mode 100644 index a717c070..00000000 --- a/db/views/19_streams_wct_vw.sql +++ /dev/null @@ -1,49 +0,0 @@ -drop view if exists bcfishpass.streams_wct_vw cascade; - -create view bcfishpass.streams_wct_vw as -select - s.segmented_stream_id, - s.linear_feature_id, - s.edge_type, - s.blue_line_key, - s.watershed_key, - s.watershed_group_code, - s.downstream_route_measure, - s.length_metre, - s.waterbody_key, - s.wscode_ltree::text as wscode, - s.localcode_ltree::text as localcode, - s.gnis_name, - s.stream_order, - s.stream_magnitude, - s.gradient, - s.feature_code, - s.upstream_route_measure, - s.upstream_area_ha, - s.map_upstream, - s.channel_width, - s.mad_m3s, - s.stream_order_parent, - s.stream_order_max, - array_to_string(a.barriers_wct_dnstr, ';') as barriers_wct_dnstr, - array_to_string(a.barriers_anthropogenic_dnstr, ';') as barriers_anthropogenic_dnstr, - array_to_string(a.barriers_pscis_dnstr, ';') as barriers_pscis_dnstr, - array_to_string(a.barriers_dams_dnstr, ';') as barriers_dams_dnstr, - array_to_string(a.barriers_dams_hydro_dnstr, ';') as barriers_dams_hydro_dnstr, - array_to_string(a.crossings_dnstr, ';') as crossings_dnstr, - a.obsrvtn_upstr_wct, - a.dam_dnstr_ind, - a.dam_hydro_dnstr_ind, - a.remediated_dnstr_ind, - h.spawning_wct as spawning, - h.rearing_wct as rearing, - hk.spawning_wct as spawning_known, - hk.rearing_wct as rearing_known, - m.mapping_code_wct as mapping_code, - s.geom -from bcfishpass.streams s -left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id -left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id -left outer join bcfishpass.streams_mapping_code_vw m on s.segmented_stream_id = m.segmented_stream_id -left outer join bcfishpass.streams_habitat_known_vw hk on s.segmented_stream_id = hk.segmented_stream_id -where cardinality(a.barriers_wct_dnstr) = 0; \ No newline at end of file diff --git a/db/views/20_freshwater_fish_habitat_accessibility_model.sql b/db/views/20_freshwater_fish_habitat_accessibility_model.sql index e988f860..4ff4f5c9 100644 --- a/db/views/20_freshwater_fish_habitat_accessibility_model.sql +++ b/db/views/20_freshwater_fish_habitat_accessibility_model.sql @@ -1,7 +1,6 @@ -- for publication to DataBC Catalouge -- freshwater_fish_habitat_accessibility_MODEL.gpkg.zip -drop view if exists bcfishpass.freshwater_fish_habitat_accessibility_model_vw; create view bcfishpass.freshwater_fish_habitat_accessibility_model_vw as select s.segmented_stream_id, @@ -47,14 +46,12 @@ left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id -- no views required for barrier tables, they can be used directly (only change would be renaming wscode/localcode) -- dump observations for salmon and steelhead used in this analysis -drop view if exists bcfishpass.freshwater_fish_habitat_accessibility_model_observations_vw; create view bcfishpass.freshwater_fish_habitat_accessibility_model_observations_vw as select * from bcfishpass.observations_vw where species_code in ('CH','CM','CO','PK','SK','ST'); -- create view of crossings with just salmon/steelhead related columns -drop view if exists bcfishpass.freshwater_fish_habitat_accessibility_model_crossings_vw; create view bcfishpass.freshwater_fish_habitat_accessibility_model_crossings_vw as select c.aggregated_crossings_id, diff --git a/db/views/wcrp_barrier_count_vw.sql b/db/views/wcrp_barrier_count_vw.sql index 8d278e5f..d5a60633 100644 --- a/db/views/wcrp_barrier_count_vw.sql +++ b/db/views/wcrp_barrier_count_vw.sql @@ -1,4 +1,3 @@ -drop view if exists bcfishpass.wcrp_barrier_count_vw; create view bcfishpass.wcrp_barrier_count_vw as with model_status as ( select diff --git a/db/views/wcrp_habitat_connectivity_status_vw.sql b/db/views/wcrp_habitat_connectivity_status_vw.sql index 45bb9c55..a7da8d66 100644 --- a/db/views/wcrp_habitat_connectivity_status_vw.sql +++ b/db/views/wcrp_habitat_connectivity_status_vw.sql @@ -1,9 +1,6 @@ -- summarize spawning/rearing/spawning&rearing habitat lengths per group, by accessibility -drop view if exists bcfishpass.wcrp_habitat_connectivity_status_vw; - create view bcfishpass.wcrp_habitat_connectivity_status_vw as - with length_totals as ( -- all spawning (ch/co/st/sk/wct) - calculation is simple, just add it up diff --git a/db/views/wsg_crossing_summary.sql b/db/views/wsg_crossing_summary.sql index 0c1fe373..6f1e84e5 100644 --- a/db/views/wsg_crossing_summary.sql +++ b/db/views/wsg_crossing_summary.sql @@ -1,5 +1,3 @@ -drop view if exists bcfishpass.wsg_crossing_summary_current cascade; - create view bcfishpass.wsg_crossing_summary_current as select s.model_run_id , @@ -56,8 +54,6 @@ where l.model_run_id = (select model_run_id from bcfishpass.log order by model_r order by s.watershed_group_code, s.crossing_feature_type; -drop view if exists bcfishpass.wsg_crossing_summary_previous; - create view bcfishpass.wsg_crossing_summary_previous as select s.model_run_id , @@ -113,7 +109,6 @@ on s.model_run_id = l.model_run_id where l.model_run_id = (select model_run_id from bcfishpass.log order by model_run_id desc offset 1 limit 1) order by watershed_group_code; -drop view if exists bcfishpass.wsg_crossing_summary_diff; create view bcfishpass.wsg_crossing_summary_diff as select a.watershed_group_code , diff --git a/db/views/wsg_linear_summary.sql b/db/views/wsg_linear_summary.sql index 7cd20caf..4a7eea0b 100644 --- a/db/views/wsg_linear_summary.sql +++ b/db/views/wsg_linear_summary.sql @@ -1,4 +1,3 @@ -drop view if exists bcfishpass.wsg_linear_summary_current cascade; create view bcfishpass.wsg_linear_summary_current as select distinct on (watershed_group_code) s.model_run_id , @@ -74,7 +73,6 @@ on s.model_run_id = l.model_run_id order by s.watershed_group_code, l.date_completed desc; -drop view if exists bcfishpass.wsg_linear_summary_previous; create view bcfishpass.wsg_linear_summary_previous as select s.model_run_id , @@ -150,7 +148,7 @@ on s.model_run_id = l.model_run_id where l.date_completed = (select date_completed from bcfishpass.log order by date_completed desc offset 1 limit 1) order by watershed_group_code; -drop view if exists bcfishpass.wsg_linear_summary_diff; + create view bcfishpass.wsg_linear_summary_diff as select a.watershed_group_code , diff --git a/jobs/setup b/jobs/setup new file mode 100755 index 00000000..a0c14f07 --- /dev/null +++ b/jobs/setup @@ -0,0 +1,72 @@ +#!/bin/bash +set -euxo pipefail + +PSQL="psql $DATABASE_URL -v ON_ERROR_STOP=1" + +#------- +# set up (almost) empty db schema +# (run as db superuser) +#------- + +# create fwa schema +git clone https://github.com/smnorris/fwapg.git +cd fwapg; make .make/db; cd .. ; rm -rf fwapg + +# create bcfishobs schema (and load selected data) +git clone https://github.com/smnorris/bcfishobs.git +cd bcfishobs; make .make/setup; cd ..; rm -rf bcfishobs + +$PSQL -f db/schemas.sql + +# create empty whse tables +for table in whse_admin_boundaries.clab_indian_reserves \ + whse_admin_boundaries.clab_national_parks \ + whse_admin_boundaries.adm_nr_districts_spg \ + whse_basemapping.bcgs_20k_grid \ + whse_basemapping.dbm_mof_50k_grid \ + whse_basemapping.gba_local_reg_greenspaces_sp \ + whse_basemapping.gba_railway_structure_lines_sp \ + whse_basemapping.gba_railway_tracks_sp \ + whse_basemapping.gba_transmission_lines_sp \ + whse_basemapping.gns_geographical_names_sp \ + whse_basemapping.nts_250k_grid \ + whse_basemapping.trim_cultural_lines \ + whse_basemapping.trim_cultural_points \ + whse_basemapping.trim_ebm_airfields \ + whse_basemapping.trim_ebm_ocean \ + whse_basemapping.utmg_utm_zones_sp \ + whse_cadastre.pmbc_parcel_fabric_poly_svw \ + whse_environmental_monitoring.envcan_hydrometric_stn_sp \ + whse_fish.fiss_obstacles_pnt_sp \ + whse_fish.fiss_stream_sample_sites_sp \ + whse_fish.pscis_assessment_svw \ + whse_fish.pscis_assessment_svw \ + whse_fish.pscis_design_proposal_svw \ + whse_fish.pscis_habitat_confirmation_svw \ + whse_fish.pscis_remediation_svw \ + whse_forest_tenure.ften_range_poly_svw \ + whse_forest_tenure.ften_road_section_lines_svw \ + whse_imagery_and_base_maps.mot_road_structure_sp \ + whse_legal_admin_boundaries.abms_municipalities_sp \ + whse_legal_admin_boundaries.abms_regional_districts_sp \ + whse_mineral_tenure.og_petrlm_dev_rds_pre06_pub_sp \ + whse_mineral_tenure.og_road_segment_permit_sp \ + whse_tantalis.ta_conservancy_areas_svw \ + whse_tantalis.ta_crown_tenures_svw \ + whse_tantalis.ta_park_ecores_pa_svw +do + bcdata bc2pg -e $table +done + +# create bcfishpass tables/views/functions +for sql in db/tables/*.sql ; do + $PSQL -f "$sql" +done + +for sql in db/views/*.sql ; do + $PSQL -f "$sql" +done + +for sql in db/functions/*.sql ; do + $PSQL -f "$sql" +done \ No newline at end of file diff --git a/jobs/test b/jobs/test deleted file mode 100755 index cc16f029..00000000 --- a/jobs/test +++ /dev/null @@ -1,43 +0,0 @@ -#!/bin/bash -set -euxo pipefail - -ogr2ogr \ - -f GPKG \ - test.gpkg \ - PG:$DATABASE_URL \ - -nln crossings \ - -nlt PointZM \ - -sql "select * - from bcfishpass.freshwater_fish_habitat_accessibility_model_crossings_vw - limit 100" - -ogr2ogr \ - -f GPKG \ - -append \ - -update \ - test.gpkg \ - PG:$DATABASE_URL \ - -nln barriers_salmon \ - -nlt PointZM \ - -sql "select - barriers_ch_cm_co_pk_sk_id, - barrier_type, - barrier_name, - linear_feature_id, - blue_line_key, - watershed_key, - downstream_route_measure, - wscode_ltree as wscode, - localcode_ltree as localcode, - watershed_group_code, - total_network_km, - geom - from bcfishpass.barriers_ch_cm_co_pk_sk - limit 100" - -# requires gdal >=3.7 -sozip \ - test.gpkg.zip \ - test.gpkg - -aws s3 cp test.gpkg.zip s3://bcfishpass \ No newline at end of file diff --git a/model/01_access/modelled_stream_crossings/Makefile b/model/01_access/modelled_stream_crossings/Makefile index ffa585c9..24dd6efb 100644 --- a/model/01_access/modelled_stream_crossings/Makefile +++ b/model/01_access/modelled_stream_crossings/Makefile @@ -21,61 +21,6 @@ WSGS = $(shell $(PSQL) -AtX -c "SELECT watershed_group_code FROM bcfishpass.wate rm -rf data/modelled_stream_crossings.gpkg touch $@ -# note that while modelled crossings are loaded from archive above, we still need roads/railways etc -# for further analysis -.make/download_bcdata: - # Get non-dra road data direct from BCGW, requesting full datasets (bcfishpass crossing scripts filter out what is needed) - bcdata bc2pg WHSE_FOREST_TENURE.FTEN_ROAD_SECTION_LINES_SVW - bcdata bc2pg WHSE_MINERAL_TENURE.OG_ROAD_SEGMENT_PERMIT_SP --primary_key og_road_segment_permit_id - bcdata bc2pg WHSE_MINERAL_TENURE.OG_PETRLM_DEV_RDS_PRE06_PUB_SP --primary_key og_petrlm_dev_rd_pre06_pub_id - $(PSQL) -c "truncate whse_basemapping.gba_railway_tracks_sp" # railway tracks table must already exist, just refresh - bcdata bc2pg WHSE_BASEMAPPING.GBA_RAILWAY_TRACKS_SP --primary_key railway_track_id -a - bcdata bc2pg WHSE_BASEMAPPING.GBA_RAILWAY_STRUCTURE_LINES_SP --primary_key RAILWAY_STRUCTURE_LINE_ID - bcdata bc2pg WHSE_IMAGERY_AND_BASE_MAPS.MOT_ROAD_STRUCTURE_SP --primary_key HWY_STRUCTURE_CLASS_ID - # get dra from ftp - wget --trust-server-names -qNP data ftp://ftp.geobc.gov.bc.ca/sections/outgoing/bmgs/DRA_Public/dgtl_road_atlas.gdb.zip - unzip -qun data/dgtl_road_atlas.gdb.zip -d data - ogr2ogr \ - -f PostgreSQL \ - "PG:$(DATABASE_URL)" \ - -overwrite \ - -lco GEOMETRY_NAME=geom \ - -lco FID=transport_line_id \ - -nln whse_basemapping.transport_line \ - data/dgtl_road_atlas.gdb \ - TRANSPORT_LINE - # load the code tables - ogr2ogr \ - -f PostgreSQL \ - "PG:$(DATABASE_URL)" \ - -overwrite \ - -nln whse_basemapping.transport_line_type_code \ - data/dgtl_road_atlas.gdb \ - TRANSPORT_LINE_TYPE_CODE - ogr2ogr \ - -f PostgreSQL \ - "PG:$(DATABASE_URL)" \ - -overwrite \ - -nln whse_basemapping.transport_line_surface_code \ - data/dgtl_road_atlas.gdb \ - TRANSPORT_LINE_SURFACE_CODE - ogr2ogr \ - -f PostgreSQL \ - "PG:$(DATABASE_URL)" \ - -overwrite \ - -nln whse_basemapping.transport_line_divided_code \ - data/dgtl_road_atlas.gdb \ - TRANSPORT_LINE_DIVIDED_CODE - ogr2ogr \ - -f PostgreSQL \ - "PG:$(DATABASE_URL)" \ - -overwrite \ - -nln whse_basemapping.transport_line_structure_code \ - data/dgtl_road_atlas.gdb \ - TRANSPORT_LINE_STRUCTURE_CODE - rm -rf data/dgtl_road_atlas.gdb - touch $@ - # run the overlays/analysis .make/modelled_stream_crossings: .make/download_archive .make/download_bcdata $(PSQL) -f sql/01_create_output_table.sql diff --git a/model/01_access/pscis/pscis.sh b/model/01_access/pscis/pscis.sh index 71a8162d..3e37e3dc 100755 --- a/model/01_access/pscis/pscis.sh +++ b/model/01_access/pscis/pscis.sh @@ -9,39 +9,8 @@ set -euxo pipefail # -------- PSQL="psql $DATABASE_URL -v ON_ERROR_STOP=1" -# download the public views from DataBC -bcdata bc2pg WHSE_FISH.PSCIS_ASSESSMENT_SVW -bcdata bc2pg WHSE_FISH.PSCIS_DESIGN_PROPOSAL_SVW -bcdata bc2pg WHSE_FISH.PSCIS_HABITAT_CONFIRMATION_SVW -bcdata bc2pg WHSE_FISH.PSCIS_REMEDIATION_SVW - -$PSQL -f sql/01_pscis_points_all.sql # combine all points into single table -$PSQL -f sql/02_pscis_streams_150m.sql # make preliminary matches of points to streams within 150m -$PSQL -f sql/04_pscis.sql # make output table -$PSQL -f sql/05_pscis_points_duplicates.sql # note duplicates for QA - -# todo - get elevation of pscis points not matched to streams -# (requires download of large extent of DEM and setting env var $BCDEM, not included for now) -# $PSQL -c "drop table if exists bcfishpass.pscis_not_matched_to_streams_elevation" -# $PSQL -c "create table bcfishpass.pscis_not_matched_to_streams_elevation (stream_crossing_id integer, elevation double precision)" -# $PSQL -t -c "SELECT -# json_build_object( -# 'type', 'FeatureCollection', -# 'features', json_agg(ST_AsGeoJSON(t.*)::json) -# ) -# FROM ( -# SELECT -# a.stream_crossing_id, -# a.geom -# FROM bcfishpass.pscis_points_all a -# LEFT OUTER JOIN bcfishpass.pscis b -# ON a.stream_crossing_id = b.stream_crossing_id -# WHERE b.stream_crossing_id IS NULL -# ) AS t" | -# rio -q pointquery -r $BCDEM | \ -# jq '.features[].properties | [.stream_crossing_id, .value]' | \ -# jq -r --slurp '.[] | @csv' | \ -# $PSQL -c "\copy bcfishpass.pscis_not_matched_to_streams_elevation FROM STDIN delimiter ',' csv" - -# create and load table pscis_not_matched_to_streams -$PSQL -f sql/06_pscis_not_matched_to_streams.sql \ No newline at end of file +$PSQL -f sql/01_pscis_points_all.sql # combine all points into single table +$PSQL -f sql/02_pscis_streams_150m.sql # make preliminary matches of points to streams within 150m +$PSQL -f sql/04_pscis.sql # make output table +$PSQL -f sql/05_pscis_points_duplicates.sql # note duplicates for QA +$PSQL -f sql/06_pscis_not_matched_to_streams.sql # create and load table pscis_not_matched_to_streams \ No newline at end of file From 2db60d1fae89db80324ffd74f9cce48b9e7b5615 Mon Sep 17 00:00:00 2001 From: Simon Norris Date: Tue, 27 Feb 2024 16:46:00 -0800 Subject: [PATCH 02/10] remove crown tenures, add missing bands layer --- jobs/setup | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/jobs/setup b/jobs/setup index a0c14f07..cbeca14c 100755 --- a/jobs/setup +++ b/jobs/setup @@ -22,6 +22,7 @@ $PSQL -f db/schemas.sql for table in whse_admin_boundaries.clab_indian_reserves \ whse_admin_boundaries.clab_national_parks \ whse_admin_boundaries.adm_nr_districts_spg \ + whse_admin_boundaries.adm_indian_reserves_bands_sp \ whse_basemapping.bcgs_20k_grid \ whse_basemapping.dbm_mof_50k_grid \ whse_basemapping.gba_local_reg_greenspaces_sp \ @@ -52,7 +53,6 @@ for table in whse_admin_boundaries.clab_indian_reserves \ whse_mineral_tenure.og_petrlm_dev_rds_pre06_pub_sp \ whse_mineral_tenure.og_road_segment_permit_sp \ whse_tantalis.ta_conservancy_areas_svw \ - whse_tantalis.ta_crown_tenures_svw \ whse_tantalis.ta_park_ecores_pa_svw do bcdata bc2pg -e $table From 7a34cfa6895b701e8d4745f7a99da1a3a776809b Mon Sep 17 00:00:00 2001 From: Simon Norris Date: Wed, 28 Feb 2024 11:21:40 -0800 Subject: [PATCH 03/10] make script executable --- jobs/freshwater_fish_habitat_accessibility_model | 0 1 file changed, 0 insertions(+), 0 deletions(-) mode change 100644 => 100755 jobs/freshwater_fish_habitat_accessibility_model diff --git a/jobs/freshwater_fish_habitat_accessibility_model b/jobs/freshwater_fish_habitat_accessibility_model old mode 100644 new mode 100755 From a0714e63e65c4debc837073a2f036305051f4856 Mon Sep 17 00:00:00 2001 From: Simon Norris Date: Wed, 28 Feb 2024 11:25:22 -0800 Subject: [PATCH 04/10] do not refresh obstacles when running bcfishpass --- model/01_access/falls/falls.sh | 25 +++++++++++++------------ 1 file changed, 13 insertions(+), 12 deletions(-) diff --git a/model/01_access/falls/falls.sh b/model/01_access/falls/falls.sh index 607dd1b7..ca8768d5 100755 --- a/model/01_access/falls/falls.sh +++ b/model/01_access/falls/falls.sh @@ -12,22 +12,23 @@ set -exo pipefail PSQL_CMD="psql $DATABASE_URL -v ON_ERROR_STOP=1" +# obstacles data refreshed separately (and we no longer archive, as it will soon be replace by cabd) + # Archive existing FISS obstacles data just in case we want it later, # the unique IDs aren't stable. Note that the archive is a full copy and # will be made every time this is run on a different day -if $PSQL_CMD -c "SELECT to_regclass('whse_fish.fiss_obstacles_pnt_sp')" | grep -q 'whse_fish.fiss_obstacles_pnt_sp'; then - DOWNLOAD_DATE=$($PSQL_CMD -tc \ - "SELECT replace(DATE(latest_download)::text, '-', '') \ - FROM bcdata.log \ - WHERE table_name = 'whse_fish.fiss_obstacles_pnt_sp'" \ - | sed -e 's/^[[:space:]]*//') - # just drop existing archive for given date if it aleady exists and re-archive - $PSQL_CMD -c "DROP TABLE IF EXISTS whse_fish.fiss_obstacles_pnt_sp_$DOWNLOAD_DATE" - $PSQL_CMD -c "CREATE TABLE whse_fish.fiss_obstacles_pnt_sp_$DOWNLOAD_DATE AS SELECT * FROM whse_fish.fiss_obstacles_pnt_sp" -fi - +# if $PSQL_CMD -c "SELECT to_regclass('whse_fish.fiss_obstacles_pnt_sp')" | grep -q 'whse_fish.fiss_obstacles_pnt_sp'; then +# DOWNLOAD_DATE=$($PSQL_CMD -tc \ +# "SELECT replace(DATE(latest_download)::text, '-', '') \ +# FROM bcdata.log \ +# WHERE table_name = 'whse_fish.fiss_obstacles_pnt_sp'" \ +# | sed -e 's/^[[:space:]]*//') +# # just drop existing archive for given date if it aleady exists and re-archive +# $PSQL_CMD -c "DROP TABLE IF EXISTS whse_fish.fiss_obstacles_pnt_sp_$DOWNLOAD_DATE" +# $PSQL_CMD -c "CREATE TABLE whse_fish.fiss_obstacles_pnt_sp_$DOWNLOAD_DATE AS SELECT * FROM whse_fish.fiss_obstacles_pnt_sp" +# fi # load the latest obstacles data -bcdata bc2pg WHSE_FISH.FISS_OBSTACLES_PNT_SP +# bcdata bc2pg WHSE_FISH.FISS_OBSTACLES_PNT_SP # load additional (unpublished) obstacle data (provided by the Province, 2014) mkdir -p data From 982adaa2e9054491337cce0fe075032bbbbdd172 Mon Sep 17 00:00:00 2001 From: Simon Norris Date: Wed, 28 Feb 2024 11:38:37 -0800 Subject: [PATCH 05/10] speed up setup by only requesting a single record --- jobs/setup | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/jobs/setup b/jobs/setup index cbeca14c..c0e60661 100755 --- a/jobs/setup +++ b/jobs/setup @@ -55,7 +55,7 @@ for table in whse_admin_boundaries.clab_indian_reserves \ whse_tantalis.ta_conservancy_areas_svw \ whse_tantalis.ta_park_ecores_pa_svw do - bcdata bc2pg -e $table + bcdata bc2pg -e -c 1 $table done # create bcfishpass tables/views/functions From bbfb9a3570e3901d212f32df4a95d9b788529b7b Mon Sep 17 00:00:00 2001 From: Simon Norris Date: Wed, 28 Feb 2024 15:06:51 -0800 Subject: [PATCH 06/10] add floodplains --- jobs/setup | 1 + 1 file changed, 1 insertion(+) diff --git a/jobs/setup b/jobs/setup index c0e60661..728d6892 100755 --- a/jobs/setup +++ b/jobs/setup @@ -24,6 +24,7 @@ for table in whse_admin_boundaries.clab_indian_reserves \ whse_admin_boundaries.adm_nr_districts_spg \ whse_admin_boundaries.adm_indian_reserves_bands_sp \ whse_basemapping.bcgs_20k_grid \ + whse_basemapping.cwb_floodplains_bc_area_svw \ whse_basemapping.dbm_mof_50k_grid \ whse_basemapping.gba_local_reg_greenspaces_sp \ whse_basemapping.gba_railway_structure_lines_sp \ From 640055a662e2d8bbec2cbb5e437fac99589b7c7b Mon Sep 17 00:00:00 2001 From: Simon Norris Date: Wed, 28 Feb 2024 15:10:45 -0800 Subject: [PATCH 07/10] refresh floodplains when building lateral habitat --- model/03_habitat_lateral/Makefile | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/model/03_habitat_lateral/Makefile b/model/03_habitat_lateral/Makefile index 188cc7d8..a4b68640 100644 --- a/model/03_habitat_lateral/Makefile +++ b/model/03_habitat_lateral/Makefile @@ -26,10 +26,10 @@ clean: rm -rf data rm -rf .make -# published floodplain definitions +# load published floodplain definitions .make/cwb_floodplains_bc_area_svw: mkdir -p .make - bcdata bc2pg WHSE_BASEMAPPING.CWB_FLOODPLAINS_BC_AREA_SVW + bcdata bc2pg -r WHSE_BASEMAPPING.CWB_FLOODPLAINS_BC_AREA_SVW touch $@ # ESA world landcover - download from S3 bucket From 666e2110447e508503be1abb1e7c7f2425750c29 Mon Sep 17 00:00:00 2001 From: Simon Norris Date: Wed, 28 Feb 2024 15:58:25 -0800 Subject: [PATCH 08/10] lateral updates --- model/03_habitat_lateral/Makefile | 3 ++- model/03_habitat_lateral/habitat_lateral.py | 6 +++--- 2 files changed, 5 insertions(+), 4 deletions(-) diff --git a/model/03_habitat_lateral/Makefile b/model/03_habitat_lateral/Makefile index a4b68640..ed99ba79 100644 --- a/model/03_habitat_lateral/Makefile +++ b/model/03_habitat_lateral/Makefile @@ -20,7 +20,6 @@ from ( \ all: .make/habitat_lateral clean: - $(PSQL) -c "DROP TABLE IF EXISTS whse_basemapping.cwb_floodplains_bc_area_svw" $(PSQL) -c "DROP TABLE IF EXISTS bcfishpass.habitat_lateral" $(PSQL) -c "DROP TABLE IF EXISTS bcfishpass.habitat_lateral_disconnected_rail" rm -rf data @@ -34,6 +33,7 @@ clean: # ESA world landcover - download from S3 bucket data/esa_bc.tif: + mkdir -p data aws s3 cp s3://esa-worldcover/v100/2020/map/ESA_WorldCover_10m_2020_v100_N54W123_Map.tif \ $(TMP)/ESA_WorldCover_10m_2020_v100_N54W123_Map.tif --no-sign-request aws s3 cp s3://esa-worldcover/v100/2020/map/ESA_WorldCover_10m_2020_v100_N57W120_Map.tif \ @@ -103,6 +103,7 @@ data/esa_bc.tif: # run VCA for each watershed group $(VALLEY_OUTPUTS): valley_confinement.py ../../.make/habitat_linear + mkdir -p data $(eval WSG=$(patsubst data/temp/%/valleys.tif,%,$@)) mkdir -p data/temp/$(WSG) python valley_confinement.py $(WSG) -o $@ -d data/temp/$(WSG) diff --git a/model/03_habitat_lateral/habitat_lateral.py b/model/03_habitat_lateral/habitat_lateral.py index 34f119c5..806a8cc8 100644 --- a/model/03_habitat_lateral/habitat_lateral.py +++ b/model/03_habitat_lateral/habitat_lateral.py @@ -79,7 +79,7 @@ # ----------------------- "spawning_rearing": """select st_multi((st_dump(st_union(st_buffer(s.geom, 30)))).geom) as geom - from bcfishpass.streams s + from bcfishpass.streams_vw s where s.watershed_group_code = %(wsg)s and ( @@ -118,7 +118,7 @@ ) )).geom ) as geom -from bcfishpass.streams s +from bcfishpass.streams_vw s left outer join whse_basemapping.fwa_stream_networks_channel_width cw on s.linear_feature_id = cw.linear_feature_id where watershed_group_code = %(wsg)s and @@ -157,7 +157,7 @@ ( select c.* from bcfishpass.crossings c - left outer join bcfishpass.streams s + left outer join bcfishpass.streams_vw s ON c.linear_feature_id = s.linear_feature_id AND c.downstream_route_measure > s.downstream_route_measure - .001 AND c.downstream_route_measure + .001 < s.upstream_route_measure From fb27292696d19be7112437e2e37c707fa229a008 Mon Sep 17 00:00:00 2001 From: Simon Norris Date: Wed, 28 Feb 2024 17:27:54 -0800 Subject: [PATCH 09/10] fix dem file logic, update streams queries, presume linear habitat has been built/is present in db --- model/03_habitat_lateral/Makefile | 4 +- .../03_habitat_lateral/valley_confinement.py | 42 +++++++++---------- 2 files changed, 21 insertions(+), 25 deletions(-) diff --git a/model/03_habitat_lateral/Makefile b/model/03_habitat_lateral/Makefile index ed99ba79..f28c7522 100644 --- a/model/03_habitat_lateral/Makefile +++ b/model/03_habitat_lateral/Makefile @@ -102,11 +102,11 @@ data/esa_bc.tif: $@ # run VCA for each watershed group -$(VALLEY_OUTPUTS): valley_confinement.py ../../.make/habitat_linear +$(VALLEY_OUTPUTS): valley_confinement.py mkdir -p data $(eval WSG=$(patsubst data/temp/%/valleys.tif,%,$@)) mkdir -p data/temp/$(WSG) - python valley_confinement.py $(WSG) -o $@ -d data/temp/$(WSG) + python valley_confinement.py -wsg $(WSG) -o $@ -d data/temp/$(WSG) # run lateral analysis for each watershed group $(LATERAL_OUTPUTS): $(VALLEY_OUTPUTS) habitat_lateral.py data/esa_bc.tif .make/cwb_floodplains_bc_area_svw diff --git a/model/03_habitat_lateral/valley_confinement.py b/model/03_habitat_lateral/valley_confinement.py index 2689e3db..a116a07b 100644 --- a/model/03_habitat_lateral/valley_confinement.py +++ b/model/03_habitat_lateral/valley_confinement.py @@ -173,22 +173,19 @@ def get_streams(db, bounds, minimum_drainage_area, DEM, dem_meta, data_path): SELECT s.linear_feature_id, s.wscode_ltree, - round(ua.upstream_area_ha::numeric) as upstream_area_ha, + round(s.upstream_area_ha::numeric) as upstream_area_ha, s.stream_order_parent, s.gradient, s.geom FROM bcfishpass.streams s - LEFT OUTER JOIN whse_basemapping.fwa_streams_watersheds_lut l - ON s.linear_feature_id = l.linear_feature_id - INNER JOIN whse_basemapping.fwa_watersheds_upstream_area ua - ON l.watershed_feature_id = ua.watershed_feature_id + left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id where s.geom && ST_MakeEnvelope(%(xmin)s,%(ymin)s,%(xmax)s,%(ymax)s) and s.gradient < .3 and ( - barriers_ch_cm_co_pk_sk_dnstr = array[]::text[] or - barriers_st_dnstr = array[]::text[] or - barriers_wct_dnstr = array[]::text[] or - barriers_bt_dnstr = array[]::text[] + cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0 or + cardinality(a.barriers_st_dnstr) = 0 or + cardinality(a.barriers_wct_dnstr) = 0 or + cardinality(a.barriers_bt_dnstr) = 0 ) ), sidechannels as ( @@ -196,12 +193,11 @@ def get_streams(db, bounds, minimum_drainage_area, DEM, dem_meta, data_path): s.linear_feature_id, s.wscode_ltree, 0 as upstream_area_ha, - s.stream_order_parent, + s2.stream_order_parent, s.gradient, s.geom from whse_basemapping.fwa_stream_networks_sp s - inner join streams s2 - on s.wscode_ltree = s2.wscode_ltree + inner join streams s2 on s.wscode_ltree = s2.wscode_ltree where s.geom && ST_MakeEnvelope(%(xmin)s,%(ymin)s,%(xmax)s,%(ymax)s) and s.gradient < .05 @@ -320,7 +316,7 @@ def get_precip(db, bounds, DEM, dem_meta, data_path): def valley_confinement( db_url, out_file, - watershed_group_code=None, + watershed_group_code, data_path="data", minimum_drainage_area=1000, slope_threshold=9, @@ -361,18 +357,18 @@ def valley_confinement( # load input rasters # --------------------- - # dem - if not os.path.exists(os.path.join(data_path, "dem.tif")) and watershed_group_code: - LOG.info("no existing dem") - if watershed_group_code and not dem_path: + # use dem in data_path if present + if not os.path.exists(os.path.join(data_path, "dem.tif")): + # otherwise, clip existing dem if dem_path provided + if dem_path: + LOG.info("clipping existing dem") + clip_dem(watershed_group_code, bounds, dem_path, data_path) + # if dem present and no path provided, download fresh dem + else: LOG.info("downloading dem") download_dem(watershed_group_code, bounds, data_path) - dem_path = os.path.join(data_path, "dem.tif") - if watershed_group_code and dem_path: - LOG.info("clipping dem") - clip_dem(watershed_group_code, bounds, dem_path, data_path) - dem_path = os.path.join(data_path, "dem.tif") + dem_path = os.path.join(data_path, "dem.tif") dem = rasterio.open(dem_path) dem_meta = dem.meta DEM = dem.read(1) @@ -738,7 +734,7 @@ def read_config(config_file): ) @click.option( "--dem", - type=click.Path(exists=True), + type=click.Path(), default=os.environ.get("DEM10M"), help="Path to existing 10m DEM", ) From 73c48242b88768f662baf4214a5df8804ea84d13 Mon Sep 17 00:00:00 2001 From: Simon Norris Date: Thu, 29 Feb 2024 09:42:57 -0800 Subject: [PATCH 10/10] apply data model changes to habitat_lateral.py --- model/03_habitat_lateral/habitat_lateral.py | 56 ++++++++++++--------- 1 file changed, 31 insertions(+), 25 deletions(-) diff --git a/model/03_habitat_lateral/habitat_lateral.py b/model/03_habitat_lateral/habitat_lateral.py index 806a8cc8..bd232a1b 100644 --- a/model/03_habitat_lateral/habitat_lateral.py +++ b/model/03_habitat_lateral/habitat_lateral.py @@ -62,12 +62,13 @@ "sidechannels": """select st_multi((st_dump(st_union(st_buffer(s.geom, 60)))).geom) as geom from bcfishpass.streams s + left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id where s.watershed_group_code = %(wsg)s and s.edge_type in (1000,1100,2000,2300) and ( - s.barriers_ch_cm_co_pk_sk_dnstr = array[]::text[] or - s.barriers_st_dnstr = array[]::text[] + cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0 or + cardinality(a.barriers_st_dnstr) = 0 ) and s.stream_order_parent > 5 and s.gradient <= .01 and @@ -79,30 +80,32 @@ # ----------------------- "spawning_rearing": """select st_multi((st_dump(st_union(st_buffer(s.geom, 30)))).geom) as geom - from bcfishpass.streams_vw s + from bcfishpass.streams s + left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id + left outer join bcfishpass.streams_habitat_linear_vw h on s.segmented_stream_id = h.segmented_stream_id where s.watershed_group_code = %(wsg)s and ( ( ( - barriers_st_dnstr = array[]::text[] or - barriers_ch_cm_co_pk_sk_dnstr = array[]::text[] + cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0 or + cardinality(a.barriers_st_dnstr) = 0 ) and stream_order >= 7 ) or ( ( - model_spawning_ch is true or - model_spawning_co is true or - model_spawning_sk is true or - model_spawning_st is true or - model_spawning_pk is true or - model_spawning_cm is true or - model_rearing_ch is true or - model_rearing_co is true or - model_rearing_sk is true or - model_rearing_st is true + h.spawning_ch is true or + h.spawning_co is true or + h.spawning_sk is true or + h.spawning_st is true or + h.spawning_pk is true or + h.spawning_cm is true or + h.rearing_ch is true or + h.rearing_co is true or + h.rearing_sk is true or + h.rearing_st is true ) ) );""", @@ -118,14 +121,15 @@ ) )).geom ) as geom -from bcfishpass.streams_vw s +from bcfishpass.streams s +left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id left outer join whse_basemapping.fwa_stream_networks_channel_width cw on s.linear_feature_id = cw.linear_feature_id where watershed_group_code = %(wsg)s and edge_type in (1000,1100,2000,2300) and ( - barriers_ch_cm_co_pk_sk_dnstr = array[]::text[] or - barriers_st_dnstr = array[]::text[] + cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0 or + cardinality(a.barriers_st_dnstr) = 0 );""", # ----------------------- # rail @@ -143,7 +147,7 @@ # ----------------------- "rail_bridges": """select st_multi(st_buffer(geom, 30)) as geom - from bcfishpass.crossings + from bcfishpass.crossings_vw where crossing_feature_type = 'RAIL' and barrier_status NOT IN ('POTENTIAL','BARRIER') and crossing_type_code != 'CBS' @@ -156,15 +160,16 @@ with xings as ( select c.* - from bcfishpass.crossings c - left outer join bcfishpass.streams_vw s + from bcfishpass.crossings_vw c + left outer join bcfishpass.streams s ON c.linear_feature_id = s.linear_feature_id AND c.downstream_route_measure > s.downstream_route_measure - .001 AND c.downstream_route_measure + .001 < s.upstream_route_measure AND c.watershed_group_code = s.watershed_group_code + left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id where c.crossing_feature_type = 'RAIL' and - (s.barriers_ch_cm_co_pk_sk_dnstr = array[]::text[] or s.barriers_st_dnstr = array[]::text[]) and + ( cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0 or cardinality(a.barriers_st_dnstr) = 0) and ( c.barrier_status in ('BARRIER', 'POTENTIAL') -- typical barriers or c.crossing_type_code = 'CBS' -- for floodplain connectivity, any CBS can be a barrier @@ -177,6 +182,7 @@ -- use flat endcap to ensure that the cut is done properly st_multi((st_dump(st_union(st_buffer(s.geom, 30, 'endcap=flat join=round')))).geom) as geom from bcfishpass.streams s + left outer join bcfishpass.streams_access_vw a on s.segmented_stream_id = a.segmented_stream_id left outer join xings b on FWA_Downstream( s.blue_line_key, @@ -185,14 +191,14 @@ s.localcode_ltree, b.blue_line_key, b.downstream_route_measure, - b.wscode_ltree, - b.localcode_ltree, + b.wscode, + b.localcode, true, 1 ) where s.watershed_group_code = %(wsg)s and - (s.barriers_ch_cm_co_pk_sk_dnstr = array[]::text[] or s.barriers_st_dnstr = array[]::text[]) + ( cardinality(a.barriers_ch_cm_co_pk_sk_dnstr) = 0 or cardinality(a.barriers_st_dnstr) = 0) --and --( -- (