diff --git a/etc/db/upgrades/upgrade33-v0.5.0-sailline-ancillary-data.sql b/etc/db/upgrades/upgrade33-v0.5.0-sailline-ancillary-data.sql new file mode 100644 index 0000000..f6e8a60 --- /dev/null +++ b/etc/db/upgrades/upgrade33-v0.5.0-sailline-ancillary-data.sql @@ -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 <>'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 +--