mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 06:47:07 +00:00
Add database upgrade file 42
This commit is contained in:
169
etc/db/upgrades/upgrade42-v0.6.4-notify-exclude-columns.sql
Normal file
169
etc/db/upgrades/upgrade42-v0.6.4-notify-exclude-columns.sql
Normal file
@@ -0,0 +1,169 @@
|
||||
-- Add procedure to decimate old nav data
|
||||
--
|
||||
-- New schema version: 0.6.4
|
||||
--
|
||||
-- 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 update modifies notify() to accept, as optional arguments, the
|
||||
-- names of columns that are to be *excluded* from the notification.
|
||||
-- It is intended for tables with large columns which are however of
|
||||
-- no particular interest in a notification.
|
||||
--
|
||||
-- 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_database () AS $outer$
|
||||
BEGIN
|
||||
|
||||
RAISE NOTICE 'Updating schema %', 'public';
|
||||
SET search_path TO public;
|
||||
|
||||
-- BEGIN
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.notify()
|
||||
RETURNS trigger
|
||||
LANGUAGE 'plpgsql'
|
||||
COST 100
|
||||
VOLATILE NOT LEAKPROOF
|
||||
AS $BODY$
|
||||
DECLARE
|
||||
channel text := TG_ARGV[0];
|
||||
pid text;
|
||||
payload text;
|
||||
notification text;
|
||||
payload_id integer;
|
||||
old_json jsonb;
|
||||
new_json jsonb;
|
||||
excluded_col text;
|
||||
i integer;
|
||||
BEGIN
|
||||
|
||||
-- Fetch pid
|
||||
SELECT projects.pid INTO pid FROM projects WHERE schema = TG_TABLE_SCHEMA;
|
||||
|
||||
-- Build old and new as jsonb, excluding specified columns if provided
|
||||
IF OLD IS NOT NULL THEN
|
||||
old_json := row_to_json(OLD)::jsonb;
|
||||
FOR i IN 1 .. TG_NARGS - 1 LOOP
|
||||
excluded_col := TG_ARGV[i];
|
||||
old_json := old_json - excluded_col;
|
||||
END LOOP;
|
||||
ELSE
|
||||
old_json := NULL;
|
||||
END IF;
|
||||
|
||||
IF NEW IS NOT NULL THEN
|
||||
new_json := row_to_json(NEW)::jsonb;
|
||||
FOR i IN 1 .. TG_NARGS - 1 LOOP
|
||||
excluded_col := TG_ARGV[i];
|
||||
new_json := new_json - excluded_col;
|
||||
END LOOP;
|
||||
ELSE
|
||||
new_json := NULL;
|
||||
END IF;
|
||||
|
||||
-- Build payload
|
||||
payload := json_build_object(
|
||||
'tstamp', CURRENT_TIMESTAMP,
|
||||
'operation', TG_OP,
|
||||
'schema', TG_TABLE_SCHEMA,
|
||||
'table', TG_TABLE_NAME,
|
||||
'old', old_json,
|
||||
'new', new_json,
|
||||
'pid', pid
|
||||
)::text;
|
||||
|
||||
-- Handle large payloads
|
||||
IF octet_length(payload) < 1000 THEN
|
||||
PERFORM pg_notify(channel, payload);
|
||||
ELSE
|
||||
-- Store large payload and notify with ID (as before)
|
||||
INSERT INTO notify_payloads (payload) VALUES (payload) RETURNING id INTO payload_id;
|
||||
|
||||
notification := json_build_object(
|
||||
'tstamp', CURRENT_TIMESTAMP,
|
||||
'operation', TG_OP,
|
||||
'schema', TG_TABLE_SCHEMA,
|
||||
'table', TG_TABLE_NAME,
|
||||
'pid', pid,
|
||||
'payload_id', payload_id
|
||||
)::text;
|
||||
|
||||
PERFORM pg_notify(channel, notification);
|
||||
RAISE INFO 'Payload over limit';
|
||||
END IF;
|
||||
RETURN NULL;
|
||||
END;
|
||||
$BODY$;
|
||||
|
||||
ALTER FUNCTION public.notify()
|
||||
OWNER TO postgres;
|
||||
|
||||
-- END
|
||||
|
||||
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.6.4' THEN
|
||||
RAISE EXCEPTION
|
||||
USING MESSAGE='Patch already applied';
|
||||
END IF;
|
||||
|
||||
IF current_db_version != '0.6.3' THEN
|
||||
RAISE EXCEPTION
|
||||
USING MESSAGE='Invalid database version: ' || current_db_version,
|
||||
HINT='Ensure all previous patches have been applied.';
|
||||
END IF;
|
||||
|
||||
CALL pg_temp.upgrade_database();
|
||||
END;
|
||||
$outer$ LANGUAGE plpgsql;
|
||||
|
||||
CALL pg_temp.upgrade();
|
||||
|
||||
CALL pg_temp.show_notice('Cleaning up');
|
||||
DROP PROCEDURE pg_temp.upgrade_database ();
|
||||
DROP PROCEDURE pg_temp.upgrade ();
|
||||
|
||||
CALL pg_temp.show_notice('Updating db_schema version');
|
||||
INSERT INTO public.info VALUES ('version', '{"db_schema": "0.6.4"}')
|
||||
ON CONFLICT (key) DO UPDATE
|
||||
SET value = public.info.value || '{"db_schema": "0.6.4"}' 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