mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 09:57:09 +00:00
163
etc/db/upgrades/upgrade33-v0.5.0-sailline-ancillary-data.sql
Normal file
163
etc/db/upgrades/upgrade33-v0.5.0-sailline-ancillary-data.sql
Normal file
@@ -0,0 +1,163 @@
|
||||
-- Sailline ancillary data
|
||||
--
|
||||
-- New schema version: 0.5.0
|
||||
--
|
||||
-- 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.
|
||||
--
|
||||
-- Issue #264 calls for associating sail and acquisition lines as well
|
||||
-- as indicating expected acquisition direction, and other data which
|
||||
-- cannot be provided via standard import formats such as SPS or P1/90.
|
||||
--
|
||||
-- We support this via an additional table that holds most of the required
|
||||
-- data. This data can simply be inferred from regular preplots, e.g., line
|
||||
-- direction can be deduced from preplot point order, and sail / source
|
||||
-- line offsets can be taken from P1/90 headers or from a configuration
|
||||
-- parameter. Alternatively, and in preference, the data can be provided
|
||||
-- explicitly, which is what issue #264 asks for.
|
||||
--
|
||||
-- In principle, this makes at least some of the attributes of `preplot_lines`
|
||||
-- redundant (at least `incr` and `ntba`) but we will leave them there for
|
||||
-- the time being as technical debt.
|
||||
--
|
||||
-- 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 TABLE IF NOT EXISTS preplot_saillines
|
||||
(
|
||||
sailline integer NOT NULL,
|
||||
line integer NOT NULL,
|
||||
sailline_class character(1) NOT NULL,
|
||||
line_class character(1) NOT NULL,
|
||||
incr boolean NOT NULL DEFAULT true,
|
||||
ntba boolean NOT NULL DEFAULT false,
|
||||
remarks text NOT NULL DEFAULT '',
|
||||
meta jsonb NOT NULL DEFAULT '{}'::jsonb,
|
||||
hash text NULL, -- Theoretically the info in this table could all be inferred.
|
||||
PRIMARY KEY (sailline, sailline_class, line, line_class, incr),
|
||||
CONSTRAINT fk_sailline FOREIGN KEY (sailline, sailline_class)
|
||||
REFERENCES preplot_lines (line, class)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT fk_line FOREIGN KEY (line, line_class)
|
||||
REFERENCES preplot_lines (line, class)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT fk_hash FOREIGN KEY (hash)
|
||||
REFERENCES files (hash) MATCH SIMPLE
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE CASCADE,
|
||||
CHECK (sailline_class = 'V' AND sailline_class != line_class)
|
||||
);
|
||||
|
||||
COMMENT ON TABLE preplot_saillines
|
||||
IS 'We explicitly associate each preplot sailline (aka vessel line) with zero or more source lines. This information can be inferred from preplot files, e.g., via a sailline offset value, or explicitly provided.';
|
||||
|
||||
-- Let us copy whatever information we can from existing tables or views
|
||||
|
||||
INSERT INTO preplot_saillines
|
||||
(sailline, line, sailline_class, line_class, incr, ntba, remarks, meta)
|
||||
SELECT DISTINCT
|
||||
sailline, psp.line, 'V' sailline_class, psp.class line_class, pl.incr, pl.ntba, pl.remarks, pl.meta
|
||||
FROM preplot_saillines_points psp
|
||||
INNER JOIN preplot_lines pl ON psp.sailline = pl.line AND pl.class = 'V'
|
||||
ORDER BY sailline;
|
||||
|
||||
-- We need to recreate the preplot_saillines_points view
|
||||
|
||||
CREATE OR REPLACE VIEW preplot_saillines_points AS
|
||||
SELECT psl.sailline,
|
||||
psl.ntba AS sailline_ntba,
|
||||
psl.line,
|
||||
pps.point,
|
||||
pps.class,
|
||||
pps.ntba,
|
||||
pps.geometry,
|
||||
pps.meta
|
||||
FROM preplot_saillines psl
|
||||
INNER JOIN preplot_points pps
|
||||
ON psl.line = pps.line AND psl.line_class = pps.class;
|
||||
|
||||
|
||||
|
||||
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.0' THEN
|
||||
RAISE EXCEPTION
|
||||
USING MESSAGE='Patch already applied';
|
||||
END IF;
|
||||
|
||||
IF current_db_version != '0.4.5' 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.0"}')
|
||||
ON CONFLICT (key) DO UPDATE
|
||||
SET value = public.info.value || '{"db_schema": "0.5.0"}' 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
|
||||
--
|
||||
Reference in New Issue
Block a user