/** * Migration: Add audit fields for tracking who made changes * * Fixes: No created_by/updated_by tracking on important tables * Changes: * - Add created_by and updated_by to key tables * - These are nullable to support system-generated records * * @type {import('node-pg-migrate').ColumnDefinitions | undefined} */ export const shorthands = undefined; /** * Tables that should have audit fields */ const TABLES_WITH_AUDIT_FIELDS = [ 'devices', 'device_configurations', 'device_certificates', 'subscription_plans', 'validated_events', 'analysis_results', 'weather_stations', ]; /** * @param pgm {import('node-pg-migrate').MigrationBuilder} * @param run {() => void | undefined} * @returns {Promise | void} */ export const up = (pgm) => { console.log('Adding audit fields to key tables...'); TABLES_WITH_AUDIT_FIELDS.forEach((table) => { console.log(` Adding audit fields to ${table}...`); pgm.addColumns(table, { created_by: { type: 'uuid', notNull: false, comment: 'User who created this record (null for system-generated)', }, updated_by: { type: 'uuid', notNull: false, comment: 'User who last updated this record (null for system updates)', }, }); // Add FK constraints to user_profiles pgm.addConstraint(table, `${table}_created_by_fkey`, { foreignKeys: { columns: 'created_by', references: 'user_profiles(id)', onDelete: 'SET NULL', }, }); pgm.addConstraint(table, `${table}_updated_by_fkey`, { foreignKeys: { columns: 'updated_by', references: 'user_profiles(id)', onDelete: 'SET NULL', }, }); }); // Create a function to automatically set updated_by from context // This works with the application setting a session variable pgm.sql(` -- Function to get current user from session context CREATE OR REPLACE FUNCTION get_current_user_id() RETURNS UUID AS $$ BEGIN -- Try to get user_id from session context (set by application) RETURN NULLIF(current_setting('app.current_user_id', true), '')::UUID; EXCEPTION WHEN OTHERS THEN RETURN NULL; END; $$ LANGUAGE plpgsql STABLE; COMMENT ON FUNCTION get_current_user_id() IS 'Get current user ID from session context. Returns NULL if not set. Application should call: SET LOCAL app.current_user_id = ''''; before operations.'; `); // Create triggers to automatically set audit fields TABLES_WITH_AUDIT_FIELDS.forEach((table) => { pgm.sql(` CREATE OR REPLACE FUNCTION ${table}_audit_trigger() RETURNS TRIGGER AS $$ BEGIN IF TG_OP = 'INSERT' THEN NEW.created_by = COALESCE(NEW.created_by, get_current_user_id()); NEW.updated_by = NEW.created_by; ELSIF TG_OP = 'UPDATE' THEN NEW.updated_by = COALESCE(get_current_user_id(), NEW.updated_by); END IF; RETURN NEW; END; $$ LANGUAGE plpgsql; DROP TRIGGER IF EXISTS ${table}_audit ON ${table}; CREATE TRIGGER ${table}_audit BEFORE INSERT OR UPDATE ON ${table} FOR EACH ROW EXECUTE FUNCTION ${table}_audit_trigger(); `); }); console.log('Audit fields added to key tables.'); console.log(''); console.log('Usage: Set session context before operations:'); console.log(" SET LOCAL app.current_user_id = '';"); }; /** * @param pgm {import('node-pg-migrate').MigrationBuilder} * @param run {() => void | undefined} * @returns {Promise | void} */ export const down = (pgm) => { console.log('Rolling back audit fields...'); // Drop triggers and functions TABLES_WITH_AUDIT_FIELDS.forEach((table) => { pgm.sql(` DROP TRIGGER IF EXISTS ${table}_audit ON ${table}; DROP FUNCTION IF EXISTS ${table}_audit_trigger(); `); }); // Drop the helper function pgm.sql('DROP FUNCTION IF EXISTS get_current_user_id();'); // Drop FK constraints and columns TABLES_WITH_AUDIT_FIELDS.forEach((table) => { console.log(` Removing audit fields from ${table}...`); pgm.dropConstraint(table, `${table}_created_by_fkey`, { ifExists: true }); pgm.dropConstraint(table, `${table}_updated_by_fkey`, { ifExists: true }); pgm.dropColumns(table, ['created_by', 'updated_by']); }); console.log('Audit fields rollback complete.'); };