-- Support notification payloads larger than Postgres' NOTIFY limit. -- -- New schema version: 0.4.3 -- -- ATTENTION: -- -- ENSURE YOU HAVE BACKED UP THE DATABASE BEFORE RUNNING THIS SCRIPT. -- -- -- NOTE: This upgrade affects the public schema only. -- NOTE: Each application starts a transaction, which must be committed -- or rolled back. -- -- This creates a new table where large notification payloads are stored -- temporarily and from which they might be recalled by the notification -- listeners. It also creates a purge_notifications() procedure used to -- clean up old notifications from the notifications log and finally, -- modifies notify() to support these changes. When a large payload is -- encountered, the payload is stored in the notify_payloads table and -- a trimmed down version containing a notification_id is sent to listeners -- instead. Listeners can then query notify_payloads to retrieve the full -- payloads. It is the application layer's responsibility to delete old -- notifications. -- -- To apply, run as the dougal user: -- -- psql < age_seconds; $$ LANGUAGE sql; 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.4.3' THEN RAISE EXCEPTION USING MESSAGE='Patch already applied'; END IF; IF current_db_version != '0.4.2' THEN RAISE EXCEPTION USING MESSAGE='Invalid database version: ' || current_db_version, HINT='Ensure all previous patches have been applied.'; END IF; -- This upgrade modified the `public` schema only, not individual -- project schemas. CALL pg_temp.upgrade_schema(); END; $outer$ LANGUAGE plpgsql; CALL pg_temp.upgrade(); CALL pg_temp.show_notice('Cleaning up'); DROP PROCEDURE pg_temp.upgrade_schema (); DROP PROCEDURE pg_temp.upgrade (); CALL pg_temp.show_notice('Updating db_schema version'); INSERT INTO public.info VALUES ('version', '{"db_schema": "0.4.3"}') ON CONFLICT (key) DO UPDATE SET value = public.info.value || '{"db_schema": "0.4.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 --