Files
yourpart3/backend/migrations/20260126000000-add-relationship-change-log.cjs
2026-01-26 09:54:40 +01:00

106 lines
3.5 KiB
JavaScript

/* eslint-disable */
'use strict';
/** Log-Tabelle für alle Änderungen an relationship und marriage_proposals (keine Einträge werden gelöscht).
* Hilft zu analysieren, warum z.B. Werbungen um einen Partner über Nacht verschwinden. */
module.exports = {
async up(queryInterface, Sequelize) {
await queryInterface.sequelize.query(`
CREATE TABLE IF NOT EXISTS falukant_log.relationship_change_log (
id serial PRIMARY KEY,
changed_at timestamp with time zone NOT NULL DEFAULT CURRENT_TIMESTAMP,
table_name character varying(64) NOT NULL,
operation character varying(16) NOT NULL,
record_id integer,
payload_old jsonb,
payload_new jsonb
);
`);
await queryInterface.sequelize.query(`
CREATE INDEX IF NOT EXISTS relationship_change_log_changed_at_idx
ON falukant_log.relationship_change_log (changed_at);
`);
await queryInterface.sequelize.query(`
CREATE INDEX IF NOT EXISTS relationship_change_log_table_operation_idx
ON falukant_log.relationship_change_log (table_name, operation);
`);
const triggerFunction = `
CREATE OR REPLACE FUNCTION falukant_log.log_relationship_change()
RETURNS TRIGGER AS $$
DECLARE
v_record_id INTEGER;
v_payload_old JSONB;
v_payload_new JSONB;
BEGIN
IF TG_OP = 'INSERT' THEN
v_record_id := NEW.id;
v_payload_old := NULL;
v_payload_new := to_jsonb(NEW);
ELSIF TG_OP = 'UPDATE' THEN
v_record_id := NEW.id;
v_payload_old := to_jsonb(OLD);
v_payload_new := to_jsonb(NEW);
ELSIF TG_OP = 'DELETE' THEN
v_record_id := OLD.id;
v_payload_old := to_jsonb(OLD);
v_payload_new := NULL;
END IF;
INSERT INTO falukant_log.relationship_change_log (
table_name,
operation,
record_id,
payload_old,
payload_new
) VALUES (
TG_TABLE_NAME,
TG_OP,
v_record_id,
v_payload_old,
v_payload_new
);
IF TG_OP = 'DELETE' THEN
RETURN OLD;
ELSE
RETURN NEW;
END IF;
END;
$$ LANGUAGE plpgsql;
`;
await queryInterface.sequelize.query(triggerFunction);
await queryInterface.sequelize.query(`
DROP TRIGGER IF EXISTS trg_log_relationship_change ON falukant_data.relationship;
CREATE TRIGGER trg_log_relationship_change
AFTER INSERT OR UPDATE OR DELETE ON falukant_data.relationship
FOR EACH ROW
EXECUTE FUNCTION falukant_log.log_relationship_change();
`);
await queryInterface.sequelize.query(`
DROP TRIGGER IF EXISTS trg_log_relationship_change ON falukant_data.marriage_proposals;
CREATE TRIGGER trg_log_relationship_change
AFTER INSERT OR UPDATE OR DELETE ON falukant_data.marriage_proposals
FOR EACH ROW
EXECUTE FUNCTION falukant_log.log_relationship_change();
`);
},
async down(queryInterface, Sequelize) {
await queryInterface.sequelize.query(`
DROP TRIGGER IF EXISTS trg_log_relationship_change ON falukant_data.relationship;
`);
await queryInterface.sequelize.query(`
DROP TRIGGER IF EXISTS trg_log_relationship_change ON falukant_data.marriage_proposals;
`);
await queryInterface.sequelize.query(`
DROP FUNCTION IF EXISTS falukant_log.log_relationship_change();
`);
await queryInterface.sequelize.query(`
DROP TABLE IF EXISTS falukant_log.relationship_change_log;
`);
},
};