mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 10:37:07 +00:00
119
etc/db/upgrades/upgrade34-v0.5.1-fix-sequences-detail-view.sql
Normal file
119
etc/db/upgrades/upgrade34-v0.5.1-fix-sequences-detail-view.sql
Normal file
@@ -0,0 +1,119 @@
|
||||
-- Sailline ancillary data
|
||||
--
|
||||
-- New schema version: 0.5.1
|
||||
--
|
||||
-- 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.
|
||||
--
|
||||
-- The sequences_detail view wrongly associates source lines and shot
|
||||
-- points when it should be associating saillines and shot points instead.
|
||||
--
|
||||
-- This updates fixes that issue (#307).
|
||||
--
|
||||
-- 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 sequences_detail
|
||||
AS
|
||||
SELECT rl.sequence,
|
||||
rl.line AS sailline,
|
||||
rs.line,
|
||||
rs.point,
|
||||
rs.tstamp,
|
||||
rs.objref AS objrefraw,
|
||||
fs.objref AS objreffinal,
|
||||
st_transform(pp.geometry, 4326) AS geometrypreplot,
|
||||
st_transform(rs.geometry, 4326) AS geometryraw,
|
||||
st_transform(fs.geometry, 4326) AS geometryfinal,
|
||||
ij_error(rs.line::double precision, rs.point::double precision, rs.geometry) AS errorraw,
|
||||
ij_error(rs.line::double precision, rs.point::double precision, fs.geometry) AS errorfinal,
|
||||
json_build_object('preplot', pp.meta, 'raw', rs.meta, 'final', fs.meta) AS meta
|
||||
FROM raw_lines rl
|
||||
INNER JOIN preplot_saillines psl ON rl.line = psl.sailline
|
||||
INNER JOIN raw_shots rs ON rs.sequence = rl.sequence AND rs.line = psl.line
|
||||
INNER JOIN preplot_points pp ON psl.line = pp.line AND psl.line_class = pp.class AND rs.point = pp.point
|
||||
LEFT JOIN final_shots fs ON rl.sequence = fs.sequence AND rs.point = fs.point;
|
||||
|
||||
ALTER TABLE sequences_detail
|
||||
OWNER TO postgres;
|
||||
|
||||
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.1' THEN
|
||||
RAISE EXCEPTION
|
||||
USING MESSAGE='Patch already applied';
|
||||
END IF;
|
||||
|
||||
IF current_db_version != '0.5.0' 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.1"}')
|
||||
ON CONFLICT (key) DO UPDATE
|
||||
SET value = public.info.value || '{"db_schema": "0.5.1"}' 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