Basic activity log for changes to patch comment table.
authorRobert Haas <[email protected]>
Mon, 13 Jul 2009 02:49:00 +0000 (22:49 -0400)
committerRobert Haas <[email protected]>
Mon, 13 Jul 2009 04:37:09 +0000 (00:37 -0400)
etc/audit.sql
etc/table.sql
etc/view.sql
perl-lib/PgCommitFest/PatchComment.pm

index fc5c8141c3e4f9ef5f5adf0897613f352ca92dbc..234d27819ae7c5b7e012d565a30bf363ce7dc898 100644 (file)
@@ -147,3 +147,77 @@ BEGIN
        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;
index 7f9f2ab0e18dc370e8e5c21d36212ca9b32a056b..6ec086265b54297c6cb2d2809385a159c7c6c1de 100644 (file)
@@ -84,3 +84,7 @@ CREATE TABLE patch_comment (
        creation_time                   timestamp with time zone not null default now(),
        PRIMARY KEY (id)
 );
+ALTER TABLE patch_comment
+       ADD COLUMN last_updater varchar,
+       ADD COLUMN last_updated_time timestamp with time zone not null
+               default now();
index 3b85b4b2f9747074f744fbc56361f61c140fa547..0e19de72cc908ff127b72e37e8eefae5608dd2f3 100644 (file)
@@ -43,4 +43,15 @@ SELECT v.commitfest_id, v.last_updated_time, v.last_updater,
        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;
index ccc804c77408e65e63210e5675573cd9cecb8a9a..e3993faf3189226f906ddd26223de7938d04bf81 100644 (file)
@@ -81,6 +81,8 @@ EOM
 
        # Handle commit.
        if ($r->cgi('go') && ! $r->is_error()) {
+               $value{'last_updated_time'} = \'now()';
+               $value{'last_updater'} = $aa->{'userid'};
                if (defined $id) {
                        $r->db->update('patch_comment', { 'id' => $id }, \%value);
                }