diff --git a/etc/db/upgrades/upgrade36-v0.5.3-fix-final_lines_summary-view.sql b/etc/db/upgrades/upgrade36-v0.5.3-fix-final_lines_summary-view.sql new file mode 100644 index 0000000..441161a --- /dev/null +++ b/etc/db/upgrades/upgrade36-v0.5.3-fix-final_lines_summary-view.sql @@ -0,0 +1,132 @@ +-- Fix final_lines_summary view +-- +-- New schema version: 0.5.3 +-- +-- 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. +-- +-- This fixes a long-standing bug, where if the sail and source lines are +-- the same, the number of missing shots will be miscounted. +-- +-- This update fixes #313. +-- +-- To apply, run as the dougal user: +-- +-- psql <= s.fsp AND preplot_points.point <= s.lsp OR preplot_points.point >= s.lsp AND preplot_points.point <= s.fsp))) - s.num_preplots AS missing_shots, + s.length, + s.azimuth, + fl.remarks, + fl.meta + FROM summary s + JOIN final_lines fl USING (sequence); + + ALTER TABLE final_lines_summary + 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.3' THEN + RAISE EXCEPTION + USING MESSAGE='Patch already applied'; + END IF; + + IF current_db_version != '0.5.2' 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.3"}') +ON CONFLICT (key) DO UPDATE + SET value = public.info.value || '{"db_schema": "0.5.3"}' 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 +--