mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 07:57:07 +00:00
146 lines
4.1 KiB
PL/PgSQL
146 lines
4.1 KiB
PL/PgSQL
-- Fix preplot_lines_summary view
|
|
--
|
|
-- New schema version: 0.5.4
|
|
--
|
|
-- ATTENTION:
|
|
--
|
|
-- ENSURE YOU HAVE BACKED UP THE DATABASE BEFORE RUNNING THIS SCRIPT.
|
|
--
|
|
--
|
|
-- NOTE: This upgrade affects all schemas in the database.
|
|
-- NOTE: Each application starts a transaction, which must be committed
|
|
-- or rolled back.
|
|
--
|
|
-- Fixes upgrade 35 (0.5.2). The original description of 0.5.2 is included
|
|
-- below for ease of reference:
|
|
--
|
|
-- Following introduction of `preplot_saillines` (0.5.0), the incr and
|
|
-- ntba statuses are stored in a separate table, not in `preplot_lines`
|
|
-- (TODO: a future upgrade should remove those columns from `preplot_lines`)
|
|
--
|
|
-- Now any views referencing `incr` and `ntba` must be updated to point to
|
|
-- the new location of those attributes.
|
|
--
|
|
-- This update fixes #312.
|
|
--
|
|
-- To apply, run as the dougal user:
|
|
--
|
|
-- psql <<EOF
|
|
-- \i $THIS_FILE
|
|
-- COMMIT;
|
|
-- EOF
|
|
--
|
|
-- NOTE: It can be applied multiple times without ill effect.
|
|
--
|
|
|
|
BEGIN;
|
|
|
|
CREATE OR REPLACE PROCEDURE pg_temp.show_notice (notice text) AS $$
|
|
BEGIN
|
|
RAISE NOTICE '%', notice;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE PROCEDURE pg_temp.upgrade_survey_schema (schema_name text) AS $outer$
|
|
BEGIN
|
|
|
|
RAISE NOTICE 'Updating schema %', schema_name;
|
|
-- We need to set the search path because some of the trigger
|
|
-- functions reference other tables in survey schemas assuming
|
|
-- they are in the search path.
|
|
EXECUTE format('SET search_path TO %I,public', schema_name);
|
|
|
|
CREATE OR REPLACE VIEW preplot_lines_summary
|
|
AS
|
|
WITH summary AS (
|
|
SELECT DISTINCT pp.line,
|
|
pp.class,
|
|
first_value(pp.point) OVER w AS p0,
|
|
last_value(pp.point) OVER w AS p1,
|
|
count(pp.point) OVER w AS num_points,
|
|
st_distance(first_value(pp.geometry) OVER w, last_value(pp.geometry) OVER w) AS length,
|
|
st_azimuth(first_value(pp.geometry) OVER w, last_value(pp.geometry) OVER w) * 180::double precision / pi() AS azimuth0,
|
|
st_azimuth(last_value(pp.geometry) OVER w, first_value(pp.geometry) OVER w) * 180::double precision / pi() AS azimuth1
|
|
FROM preplot_points pp
|
|
WHERE pp.class = 'V'::bpchar
|
|
WINDOW w AS (PARTITION BY pp.line ORDER BY pp.point ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING)
|
|
)
|
|
SELECT DISTINCT psl.sailline AS line,
|
|
CASE
|
|
WHEN psl.incr THEN s.p0
|
|
ELSE s.p1
|
|
END AS fsp,
|
|
CASE
|
|
WHEN psl.incr THEN s.p1
|
|
ELSE s.p0
|
|
END AS lsp,
|
|
s.num_points,
|
|
s.length,
|
|
CASE
|
|
WHEN psl.incr THEN s.azimuth0
|
|
ELSE s.azimuth1
|
|
END AS azimuth,
|
|
psl.incr,
|
|
psl.remarks
|
|
FROM summary s
|
|
JOIN preplot_saillines psl ON psl.sailline_class = s.class AND s.line = psl.sailline
|
|
ORDER BY psl.sailline, psl.incr;
|
|
|
|
ALTER TABLE preplot_lines_summary
|
|
OWNER TO postgres;
|
|
COMMENT ON VIEW preplot_lines_summary
|
|
IS 'Summarises ''V'' (vessel sailline) preplot lines.';
|
|
|
|
|
|
|
|
END;
|
|
$outer$ LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE PROCEDURE pg_temp.upgrade () AS $outer$
|
|
DECLARE
|
|
row RECORD;
|
|
current_db_version TEXT;
|
|
BEGIN
|
|
|
|
SELECT value->>'db_schema' INTO current_db_version FROM public.info WHERE key = 'version';
|
|
|
|
IF current_db_version >= '0.5.4' THEN
|
|
RAISE EXCEPTION
|
|
USING MESSAGE='Patch already applied';
|
|
END IF;
|
|
|
|
IF current_db_version != '0.5.3' THEN
|
|
RAISE EXCEPTION
|
|
USING MESSAGE='Invalid database version: ' || current_db_version,
|
|
HINT='Ensure all previous patches have been applied.';
|
|
END IF;
|
|
|
|
FOR row IN
|
|
SELECT schema_name FROM information_schema.schemata
|
|
WHERE schema_name LIKE 'survey_%'
|
|
ORDER BY schema_name
|
|
LOOP
|
|
CALL pg_temp.upgrade_survey_schema(row.schema_name);
|
|
END LOOP;
|
|
END;
|
|
$outer$ LANGUAGE plpgsql;
|
|
|
|
CALL pg_temp.upgrade();
|
|
|
|
CALL pg_temp.show_notice('Cleaning up');
|
|
DROP PROCEDURE pg_temp.upgrade_survey_schema (schema_name text);
|
|
DROP PROCEDURE pg_temp.upgrade ();
|
|
|
|
CALL pg_temp.show_notice('Updating db_schema version');
|
|
INSERT INTO public.info VALUES ('version', '{"db_schema": "0.5.4"}')
|
|
ON CONFLICT (key) DO UPDATE
|
|
SET value = public.info.value || '{"db_schema": "0.5.4"}' WHERE public.info.key = 'version';
|
|
|
|
|
|
CALL pg_temp.show_notice('All done. You may now run "COMMIT;" to persist the changes');
|
|
DROP PROCEDURE pg_temp.show_notice (notice text);
|
|
|
|
--
|
|
--NOTE Run `COMMIT;` now if all went well
|
|
--
|