RETURN array_to_string(v, ', ');
END
$$ LANGUAGE plpgsql;
+
+CREATE TABLE patch_comment_audit (
+ id integer not null,
+ patch_id integer not null,
+ change_type varchar not null,
+ changed_fields varchar[] not null,
+ commitfest_id integer not null,
+ patch_name varchar not null,
+ patch_comment_type_id integer not null,
+ message_id varchar,
+ content varchar,
+ last_updater varchar,
+ last_updated_time timestamp with time zone not null
+);
+
+CREATE OR REPLACE FUNCTION patch_comment_audit() RETURNS trigger AS $$
+DECLARE
+ cf varchar[] := '{}'::varchar[];
+ cid integer;
+ pname varchar;
+BEGIN
+ IF (TG_OP = 'DELETE') THEN
+ NEW := OLD;
+ NEW.last_updated_time := now();
+ END IF;
+ IF (TG_OP = 'UPDATE') THEN
+ IF (OLD.last_updated_time = NEW.last_updated_time) THEN
+ -- Some kind of system update, just ignore it.
+ RETURN NULL;
+ END IF;
+ cf := CASE WHEN OLD.patch_comment_type_id != NEW.patch_comment_type_id
+ THEN '{patch_comment_type_id}'::varchar[]
+ ELSE '{}'::varchar[] END
+ || CASE WHEN OLD.message_id != NEW.message_id
+ THEN '{message_id}'::varchar[]
+ ELSE '{}'::varchar[] END
+ || CASE WHEN OLD.content != NEW.content
+ THEN '{content}'::varchar[]
+ ELSE '{}'::varchar[] END;
+ END IF;
+ SELECT INTO cid, pname
+ t.commitfest_id, p.name
+ FROM
+ patch p
+ JOIN commitfest_topic t ON p.commitfest_topic_id = t.id
+ WHERE
+ p.id = NEW.patch_id;
+ IF (TG_OP = 'INSERT') THEN
+ cf := ARRAY['patch_comment_type_id', 'message_id', 'content' ];
+ END IF;
+ INSERT INTO patch_comment_audit
+ (id, patch_id, change_type, changed_fields, commitfest_id, patch_name,
+ patch_comment_type_id, message_id, content, last_updater,
+ last_updated_time)
+ VALUES
+ (NEW.id, NEW.patch_id, TG_OP, cf, cid, pname,
+ NEW.patch_comment_type_id, NEW.message_id, NEW.content,
+ NEW.last_updater, NEW.last_updated_time);
+ RETURN NULL;
+END
+$$ LANGUAGE plpgsql;
+
+CREATE TRIGGER patch_comment_audit
+ AFTER INSERT OR UPDATE OR DELETE ON patch_comment
+ FOR EACH ROW EXECUTE PROCEDURE patch_comment_audit();
+
+CREATE OR REPLACE FUNCTION patch_comment_audit_details(patch_comment_audit)
+ RETURNS text AS $$
+SELECT
+ (SELECT name FROM patch_comment_type WHERE id = $1.patch_comment_type_id)
+ || ': ' || $1.content
+ || CASE WHEN $1.message_id != '' THEN ' (Message-ID: '
+ || $1.message_id || ')' ELSE '' END
+$$ LANGUAGE sql;
patch_audit_details(v) AS details
FROM
patch_audit v
+ LEFT JOIN patch p ON v.patch_id = p.id
+UNION ALL
+SELECT v.commitfest_id, v.last_updated_time, v.last_updater,
+ v.patch_name, v.patch_id,
+ CASE WHEN v.change_type = 'INSERT' THEN 'New Comment'
+ WHEN v.change_type = 'UPDATE' THEN 'Edit Comment'
+ WHEN v.change_type = 'DELETE' THEN 'Delete Comment'
+ END AS activity_type,
+ patch_comment_audit_details(v) AS details
+FROM
+ patch_comment_audit v
LEFT JOIN patch p ON v.patch_id = p.id;