From ca8dd68d1044b7e815ac4a4169b5a4425dfbf438 Mon Sep 17 00:00:00 2001 From: "D. Berge" Date: Thu, 2 Nov 2023 11:54:03 +0100 Subject: [PATCH] Add database upgrade file 32. --- ...0.4.5-materialise-view-project_summary.sql | 147 ++++++++++++++++++ 1 file changed, 147 insertions(+) create mode 100644 etc/db/upgrades/upgrade32-v0.4.5-materialise-view-project_summary.sql diff --git a/etc/db/upgrades/upgrade32-v0.4.5-materialise-view-project_summary.sql b/etc/db/upgrades/upgrade32-v0.4.5-materialise-view-project_summary.sql new file mode 100644 index 0000000..74fc2ff --- /dev/null +++ b/etc/db/upgrades/upgrade32-v0.4.5-materialise-view-project_summary.sql @@ -0,0 +1,147 @@ +-- Turn project_summary into a materialised view +-- +-- New schema version: 0.4.5 +-- +-- 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 project_summary view is quite a bottleneck. While it itself is +-- not the real culprit (rather the underlying views are), this is one +-- relatively cheap way of improving responsiveness from the client's +-- point of view. +-- We leave the details of how / when to refresh the view to the non- +-- database code. +-- +-- 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.4.5' THEN + RAISE EXCEPTION + USING MESSAGE='Patch already applied'; + END IF; + + IF current_db_version != '0.4.4' 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.4.5"}') +ON CONFLICT (key) DO UPDATE + SET value = public.info.value || '{"db_schema": "0.4.5"}' 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 +--