view schema/geoserver_views.sql @ 4582:51dc19001808 iso-areas

Added geoserver view and named style to match.
author Sascha L. Teichmann <sascha.teichmann@intevation.de>
date Tue, 08 Oct 2019 16:13:53 +0200
parents c657dec6b0fa
children 0b01fd83bc3b
line wrap: on
line source

CREATE OR REPLACE VIEW waterway.gauges_base_view AS
    SELECT
        g.location,
        isrs_asText(g.location) AS isrs_code,
        g.objname,
        g.geom,
        g.applicability_from_km,
        g.applicability_to_km,
        g.validity,
        g.zero_point,
        g.geodref,
        g.date_info,
        g.source_organization,
        g.erased,
        r.rwls AS reference_water_levels,
        wl.measure_date AS gm_measuredate,
        wl.water_level AS gm_waterlevel,
        wl.n AS gm_n_14d,
        fca.forecast_accuracy_3d,
        fca.forecast_accuracy_1d
    FROM waterway.gauges g
        LEFT JOIN (SELECT location, validity,
                    json_strip_nulls(json_object_agg(
                        coalesce(depth_reference, 'empty'), value)) AS rwls
                FROM waterway.gauges_reference_water_levels
                GROUP BY location, validity) AS r
            USING (location, validity)
        LEFT JOIN (SELECT DISTINCT ON (location)
                    location,
                    date_issue,
                    measure_date,
                    water_level,
                    count(*) OVER (PARTITION BY location) AS n
                FROM waterway.gauge_measurements
                -- consider all measurements within 14 days plus a tolerance
                WHERE measure_date
                    >= current_timestamp - '14 days 00:15'::interval
                ORDER BY location, measure_date DESC) AS wl
            USING (location)
        LEFT JOIN (SELECT DISTINCT ON (location)
                    location,
                    date_issue,
                    max(acc) FILTER (WHERE measure_date
                            <= current_timestamp + '1 day'::interval)
                        OVER loc_date_issue AS forecast_accuracy_1d,
                    max(acc) OVER loc_date_issue AS forecast_accuracy_3d
                FROM (SELECT location, date_issue, measure_date,
                        GREATEST(water_level - lower(conf_interval),
                            upper(conf_interval) - water_level) AS acc
                    FROM waterway.gauge_predictions
                    -- consider predictions made within last 14 days ...
                    WHERE date_issue
                        >= current_timestamp - '14 days 00:15'::interval
                        -- ... for the next three days from now
                        AND measure_date BETWEEN current_timestamp
                            AND current_timestamp + '3 days'::interval) AS acc
                WINDOW loc_date_issue AS (PARTITION BY location, date_issue)
                ORDER BY location, date_issue DESC) AS fca
            -- Show only forecasts issued with latest measurements or later
            ON fca.location = g.location AND fca.date_issue >= wl.date_issue;

CREATE OR REPLACE VIEW waterway.gauges_geoserver AS
    SELECT
        isrs_code,
        objname,
        geom,
        applicability_from_km,
        applicability_to_km,
        zero_point,
        geodref,
        date_info,
        source_organization,
        reference_water_levels,
        gm_measuredate,
        gm_waterlevel,
        gm_n_14d,
        forecast_accuracy_3d,
        forecast_accuracy_1d
    FROM waterway.gauges_base_view
    WHERE NOT erased;

CREATE OR REPLACE VIEW waterway.distance_marks_geoserver AS
    SELECT
       isrs_asText(location_code) AS location,
       geom::Geometry(POINT, 4326),
       related_enc,
       (location_code).hectometre
    FROM waterway.distance_marks_virtual;

CREATE OR REPLACE VIEW waterway.distance_marks_ashore_geoserver AS
    SELECT id,
       country,
       geom::Geometry(POINT, 4326),
       related_enc,
       hectom,
       catdis,
       position_code
    FROM waterway.distance_marks;

CREATE OR REPLACE VIEW waterway.bottlenecks_geoserver AS
    SELECT
        b.id,
        b.bottleneck_id,
        b.objnam,
        b.nobjnm,
        b.area,
        b.rb,
        b.lb,
        b.responsible_country,
        b.revisiting_time,
        b.limiting,
        b.date_info,
        b.source_organization,
        g.objname AS gauge_objname,
        g.reference_water_levels,
        fal.date_info AS fa_date_info,
        fal.critical AS fa_critical,
        g.gm_measuredate,
        g.gm_waterlevel,
        g.gm_n_14d,
        srl.date_max,
        g.forecast_accuracy_3d,
        g.forecast_accuracy_1d
    FROM waterway.bottlenecks b
        LEFT JOIN waterway.gauges_base_view g
            ON b.gauge_location = g.location AND g.validity @> current_timestamp
        LEFT JOIN (SELECT DISTINCT ON (bottleneck_id)
                    bottleneck_id, date_info, critical
                FROM waterway.fairway_availability
                ORDER BY bottleneck_id, date_info DESC) AS fal
            ON b.bottleneck_id = fal.bottleneck_id
        LEFT JOIN (SELECT DISTINCT ON (bottleneck_id)
                    bottleneck_id, max(date_info) AS date_max
                FROM waterway.sounding_results
                GROUP BY bottleneck_id
                ORDER BY bottleneck_id DESC) AS srl
            ON b.bottleneck_id = srl.bottleneck_id
    WHERE b.validity @> current_timestamp;

CREATE OR REPLACE VIEW waterway.stretches_geoserver AS
    SELECT
        s.id,
        s.name,
        (s.stretch).lower::varchar as lower,
        (s.stretch).upper::varchar as upper,
        s.area::Geometry(MULTIPOLYGON, 4326),
        s.objnam,
        s.nobjnam,
        s.date_info,
        s.source_organization,
        (SELECT string_agg(country, ', ')
            FROM users.stretch_countries
            WHERE stretch_id = s.id) AS countries,
        s.staging_done,
        min(g.gm_measuredate) AS gm_measuredate,
        min(g.gm_n_14d) AS gm_n_14d,
        max(g.forecast_accuracy_3d) AS forecast_accuracy_3d,
        max(g.forecast_accuracy_1d) AS forecast_accuracy_1d
    FROM users.stretches s
        LEFT JOIN waterway.gauges_geoserver g
            ON isrs_fromtext(g.isrs_code) <@ s.stretch
    GROUP BY s.id;

CREATE OR REPLACE VIEW waterway.sections_geoserver AS
    SELECT
        s.id,
        s.name,
        (s.section).lower::varchar as lower,
        (s.section).upper::varchar as upper,
        s.area::Geometry(MULTIPOLYGON, 4326),
        s.objnam,
        s.nobjnam,
        s.date_info,
        s.source_organization,
        s.staging_done,
        min(g.gm_measuredate) AS gm_measuredate,
        min(g.gm_n_14d) AS gm_n_14d,
        max(g.forecast_accuracy_3d) AS forecast_accuracy_3d,
        max(g.forecast_accuracy_1d) AS forecast_accuracy_1d
    FROM waterway.sections s
        LEFT JOIN waterway.gauges_geoserver g
            ON isrs_fromtext(g.isrs_code) <@ s.section
    GROUP BY s.id;

CREATE OR REPLACE VIEW waterway.bottleneck_overview AS
    SELECT
        objnam AS name,
        ST_Centroid(area)::Geometry(POINT, 4326) AS point,
        (lower(stretch)).hectometre AS from,
        (upper(stretch)).hectometre AS to,
        sr.current::text,
        responsible_country
    FROM waterway.bottlenecks bn LEFT JOIN (
        SELECT bottleneck_id, max(date_info) AS current
            FROM waterway.sounding_results
            GROUP BY bottleneck_id) sr ON sr.bottleneck_id = bn.bottleneck_id
    WHERE bn.validity @> current_timestamp
    ORDER BY objnam;

CREATE OR REPLACE VIEW waterway.sounding_results_areas_geoserver AS
  SELECT
    bottleneck_id,
    date_info,
    height,
    CAST(areas AS geometry(multipolygon, 4326)) as areas
  FROM waterway.sounding_results_iso_areas ia
  JOIN waterway.sounding_results sr ON sr.id = ia.sounding_result_id;