Basic activity log for changes to patch table.
authorRobert Haas <[email protected]>
Sun, 12 Jul 2009 03:07:05 +0000 (23:07 -0400)
committerRobert Haas <[email protected]>
Mon, 13 Jul 2009 02:41:14 +0000 (22:41 -0400)
etc/audit.sql [new file with mode: 0644]
etc/table.sql
etc/view.sql
perl-lib/PgCommitFest/CommitFest.pm
perl-lib/PgCommitFest/Handler.pm
perl-lib/PgCommitFest/Patch.pm
template/commitfest_activity.tt2 [new file with mode: 0644]
template/commitfest_search.tt2

diff --git a/etc/audit.sql b/etc/audit.sql
new file mode 100644 (file)
index 0000000..fc5c814
--- /dev/null
@@ -0,0 +1,149 @@
+CREATE TABLE patch_audit (
+       patch_id                                integer not null,
+       change_type                             varchar not null,
+       changed_fields                  varchar[] not null,
+       commitfest_id           integer not null,
+       original_name                   varchar not null,
+       from_commitfest_id              integer,
+       to_commitfest_id                integer,
+       commitfest_topic_id     integer not null,
+       name                                    varchar not null,
+       patch_status_id                 integer not null,
+       author                                  varchar not null,
+       reviewers                               varchar not null,
+       date_closed                             date,
+       last_updater                    varchar,
+       last_updated_time               timestamp with time zone not null
+);
+
+CREATE OR REPLACE FUNCTION patch_audit() RETURNS trigger AS $$
+DECLARE
+       cf varchar[] := '{}'::varchar[];
+       acid integer;
+       cid integer;
+       oname 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.commitfest_topic_id != NEW.commitfest_topic_id
+                                  THEN '{commitfest_topic_id}'::varchar[]
+                                  ELSE '{}'::varchar[] END
+                  || CASE WHEN OLD.name != NEW.name
+                                  THEN '{name}'::varchar[]
+                                  ELSE '{}'::varchar[] END
+                  || CASE WHEN OLD.patch_status_id != NEW.patch_status_id
+                                  THEN '{patch_status_id}'::varchar[]
+                                  ELSE '{}'::varchar[] END
+                  || CASE WHEN OLD.author != NEW.author
+                                  THEN '{author}'::varchar[]
+                                  ELSE '{}'::varchar[] END
+                  || CASE WHEN OLD.reviewers != NEW.reviewers
+                                  THEN '{reviewers}'::varchar[]
+                                  ELSE '{}'::varchar[] END
+                  || CASE WHEN OLD.date_closed IS DISTINCT FROM NEW.date_closed
+                                  THEN '{date_closed}'::varchar[]
+                                  ELSE '{}'::varchar[] END;
+               SELECT INTO cid
+                       commitfest_id
+               FROM
+                       commitfest_topic
+               WHERE
+                       id = NEW.commitfest_topic_id;
+               SELECT INTO acid
+                       commitfest_id
+               FROM
+                       commitfest_topic
+               WHERE
+                       id = OLD.commitfest_topic_id;
+               oname := OLD.name;
+       ELSE
+               SELECT INTO cid, acid
+                       commitfest_id, commitfest_id
+               FROM
+                       commitfest_topic
+               WHERE
+                       id = NEW.commitfest_topic_id;
+               oname := NEW.name;
+       END IF;
+       IF (TG_OP = 'INSERT') THEN
+               cf := ARRAY['commitfest_id', 'commitfest_topic_id', 'name',
+                       'patch_status_id', 'author', 'reviewers', 'date_closed'];
+       END IF;
+       INSERT INTO patch_audit
+               (patch_id, change_type, changed_fields, commitfest_id, original_name,
+                to_commitfest_id, commitfest_topic_id, name,
+                patch_status_id, author, reviewers, date_closed, last_updater,
+                last_updated_time)
+       VALUES
+               (NEW.id, TG_OP, cf, acid, oname,
+                CASE WHEN cid != acid THEN cid ELSE NULL END,
+                NEW.commitfest_topic_id, NEW.name, NEW.patch_status_id, NEW.author,
+                NEW.reviewers, NEW.date_closed, NEW.last_updater,
+                NEW.last_updated_time);
+       -- For an update that changes the CommitFest, we enter two audit records,
+       -- one under each CommitFest.
+       IF (cid != acid) THEN
+               INSERT INTO patch_audit
+                       (patch_id, change_type, changed_fields, commitfest_id,
+                        original_name,
+                        from_commitfest_id, commitfest_topic_id, name,
+                        patch_status_id, author, reviewers, date_closed, last_updater,
+                        last_updated_time)
+               VALUES
+                       (NEW.id, TG_OP, cf, cid, oname, acid,
+                        NEW.commitfest_topic_id, NEW.name, NEW.patch_status_id, NEW.author,
+                        NEW.reviewers, NEW.date_closed, NEW.last_updater,
+                        NEW.last_updated_time);
+       END IF;
+       RETURN NULL;
+END
+$$ LANGUAGE plpgsql;
+
+CREATE TRIGGER patch_audit
+       AFTER INSERT OR UPDATE OR DELETE ON patch
+       FOR EACH ROW EXECUTE PROCEDURE patch_audit();
+
+CREATE OR REPLACE FUNCTION patch_audit_details(patch_audit) RETURNS text AS $$
+DECLARE
+       v varchar[];
+BEGIN
+       IF ('name' = ANY($1.changed_fields)) THEN
+               v := v || ('Name = ' || $1.name)::varchar;
+       END IF;
+       IF ($1.from_commitfest_id IS NOT NULL) THEN
+               v := v || ('Moved From CommitFest = ' || COALESCE((SELECT name FROM
+                       commitfest WHERE id = $1.from_commitfest_id), '???'))::varchar;
+       END IF;
+       IF ($1.to_commitfest_id IS NOT NULL) THEN
+               v := v || ('Moved To CommitFest = ' || COALESCE((SELECT name FROM
+                       commitfest WHERE id = $1.to_commitfest_id), '???'))::varchar;
+       END IF;
+       IF ('commitfest_topic_id' = ANY($1.changed_fields)) THEN
+               v := v || ('Topic = ' || COALESCE((SELECT name FROM commitfest_topic
+                       WHERE id = $1.commitfest_topic_id), '???'))::varchar;
+       END IF;
+       IF ('patch_status_id' = ANY($1.changed_fields)) THEN
+               v := v || ('Patch Status = ' || COALESCE((SELECT name FROM patch_status
+                       WHERE id = $1.patch_status_id), '???'))::varchar;
+       END IF;
+       IF ('author' = ANY($1.changed_fields)) THEN
+               v := v || ('Author = ' || $1.author)::varchar;
+       END IF;
+       IF ('reviewers' = ANY($1.changed_fields)) THEN
+               v := v || ('Reviewers = ' || CASE WHEN $1.reviewers = '' THEN 'Nobody'
+                       ELSE $1.reviewers END)::varchar;
+       END IF;
+       IF ('date_closed' = ANY($1.changed_fields)) THEN
+               v := v || ('Date Closed = '
+                       || COALESCE($1.date_closed::varchar, 'NULL'))::varchar;
+       END IF;
+       RETURN array_to_string(v, ', ');
+END
+$$ LANGUAGE plpgsql;
index f7ce483f2a8f28fb587950c36b170ea19d324b4a..7f9f2ab0e18dc370e8e5c21d36212ca9b32a056b 100644 (file)
@@ -59,6 +59,10 @@ CREATE TABLE patch (
        creation_time                   timestamp with time zone not null default now(),
        PRIMARY KEY (id)
 );
+ALTER TABLE patch
+       ADD COLUMN last_updater varchar,
+       ADD COLUMN last_updated_time timestamp with time zone not null
+               default now();
 
 CREATE TABLE patch_comment_type (
        id                                              integer not null,
index c80fd3a65306810ab0d8367cba522c397995e475..3b85b4b2f9747074f744fbc56361f61c140fa547 100644 (file)
@@ -31,3 +31,16 @@ FROM
        patch_comment v
        INNER JOIN patch_comment_type pct ON v.patch_comment_type_id = pct.id
        INNER JOIN patch p ON v.patch_id = p.id;
+
+CREATE OR REPLACE VIEW commitfest_activity_log AS
+SELECT v.commitfest_id, v.last_updated_time, v.last_updater,
+       v.original_name AS patch_name,
+       p.id AS patch_id,
+       CASE WHEN v.change_type = 'INSERT' THEN 'New Patch'
+                WHEN v.change_type = 'UPDATE' THEN 'Patch Edited'
+                WHEN v.change_type = 'DELETE' THEN 'Patch Deleted'
+       END AS activity_type,
+       patch_audit_details(v) AS details
+FROM
+       patch_audit v
+       LEFT JOIN patch p ON v.patch_id = p.id;
index a4115b2ef5398d93342bcabc0c2a388ba003260f..84cee1f398d97c183f71ba4f4704539738f068e6 100644 (file)
@@ -2,6 +2,27 @@ package PgCommitFest::CommitFest;
 use strict;
 use warnings;
 
+sub activity {
+       my ($r, $extrapath) = @_;
+       my $d = setup($r, $extrapath);
+       $r->set_title('CommitFest %s: Activity Log', $d->{'name'});
+       $r->add_link('/action/commitfest_view?id=' . $d->{'id'},
+               'Back to CommitFest');
+       my $activity = $r->db->select(<<EOM, $d->{'id'});
+SELECT
+       to_char(v.last_updated_time, 'YYYY-MM-DD HH24:MI:SS') AS last_updated_time,
+       v.last_updater, v.patch_name, v.patch_id, v.activity_type, v.details
+FROM
+       commitfest_activity_log v
+WHERE
+       v.commitfest_id = ?
+ORDER BY
+       v.last_updated_time DESC
+EOM
+       $r->render_template('commitfest_activity', { 'd' => $d,
+               'activity' => $activity });
+}
+
 sub delete {
        my ($r) = @_;
        $r->authenticate('require_login' => 1, 'require_administrator' => 1);
@@ -85,9 +106,8 @@ EOM
        $r->render_template('commitfest_search', { 'list' => $list });
 }
 
-sub view {
+sub setup {
        my ($r, $extrapath) = @_;
-       my $aa = $r->authenticate();
 
        # Target commitfest can be specified either by ID, or we allow special
        # magic to fetch it by 
@@ -121,6 +141,14 @@ EOM
 SELECT id, name, commitfest_status FROM commitfest_view $sqlbit
 EOM
        $r->error_exit('CommitFest not found.') if !defined $d;
+       return $d;
+}
+
+sub view {
+       my ($r, $extrapath) = @_;
+       my $aa = $r->authenticate();
+       my $d = setup($r, $extrapath);
+       my $id = $d->{'id'};
        $r->set_title('CommitFest %s (%s)', $d->{'name'},
                $d->{'commitfest_status'});
 
@@ -165,6 +193,7 @@ EOM
 
        # Add links and render template.
        $r->add_link('/action/patch_form?commitfest=' . $id, 'New Patch');
+       $r->add_link('/action/commitfest_activity?id=' . $id, 'Activity Log');
        $r->add_link('/action/commitfest_topic_search?id=' . $id,
                'CommitFest Topics');
        if (defined $aa && $aa->{'is_administrator'}) {
index d94e0421e6c4bd999ba79d15ec040e8c8c4456bc..b269e0f1b5bfad3370f53c631d6d236272544687 100644 (file)
@@ -12,6 +12,7 @@ use Template;
 our %ACTION = (
        'login'                                     => \&PgCommitFest::Handler::login,
        'logout'                                    => \&PgCommitFest::Handler::logout,
+       'commitfest_activity'           => \&PgCommitFest::CommitFest::activity,
        'commitfest_delete'                     => \&PgCommitFest::CommitFest::delete,
        'commitfest_form'                       => \&PgCommitFest::CommitFest::form,
        'commitfest_search'                 => \&PgCommitFest::CommitFest::search,
index 5ebeb42949c2b0267def4be98bba0201d2a9a746..4a769c8bef1ad3e44b809376034df88aa4bc539c 100644 (file)
@@ -28,10 +28,16 @@ EOM
 
 sub delete {
        my ($r) = @_;
-       $r->authenticate('require_login' => 1);
+       my $aa = $r->authenticate('require_login' => 1);
        $r->set_title('Delete Patch');
        my $d;
        eval {
+               # Don't bump last_updated_time, as that would trigger an activity log
+               # record.  But do change the last_updater, so that the subsequent
+               # delete picks up the correct user id.  This is a pretty ugly kludge,
+               # but I don't immediately have a better idea.
+               $r->db->update('patch', { 'id' => $r->cgi_required_id },
+                       { 'last_updater' => $aa->{'userid'} });
                $d = $r->db->select_one(<<EOM, $r->cgi_required_id);
 DELETE FROM patch AS p
        USING commitfest_topic t
@@ -132,6 +138,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', { 'id' => $id }, \%value);
                }
diff --git a/template/commitfest_activity.tt2 b/template/commitfest_activity.tt2
new file mode 100644 (file)
index 0000000..358f2e9
--- /dev/null
@@ -0,0 +1,26 @@
+<p></p>
+
+[% IF activity.size %]
+<div class='tblBasic'>
+<table cellspacing='0' class='tblBasicGrey' style='width: 100%'>
+<tr class='firstrow'>
+  <th class='colFirst'>Time</th>
+  <th>User</th>
+  <th>Patch</th>
+  <th>Activity Type</th>
+  <th class='colLast'>Details</th>
+</tr>
+[% FOREACH a = activity %]
+<tr[% IF loop.last %] class='lastrow'[% END %]>
+  <td class='colFirstT'>[% a.last_updated_time %]</td>
+  <td class='colMidT'>[% a.last_updater %]</td>
+  <td>[% IF a.patch_id.defined %]<a href='/action/patch_view?id=[% a.patch_id %]'>[% END %][% a.patch_name | htmlsafe %][% IF a.patch_id.defined %]</a>[% END %]</td>
+  <td class='colMidT'>[% a.activity_type | html %]</td>
+  <td class='colLastT'>[% a.details %]</td>
+</tr>
+[% END %]
+</table>
+</div>
+[% ELSE %]
+<div>No activity for this CommitFest.</div>
+[% END %]
index 9a14dd633cec00d1cea706e5a7aae34757a65912..ec39ad4928e5ab2d1dcb8cd89c8acc1318af5553 100644 (file)
@@ -1,13 +1,16 @@
 <p>If you have submitted a patch to pgsql-hackers and want it to be reviewed,
 you should add it to the <a href='/action/commitfest_view/open'>Open
-CommitFest</a>.  If you want to help with the reviewing process for the
+CommitFest</a> (<a href='/action/commitfest_activity/open'>Activity Log</a>).
+If you want to help with the reviewing process for the
 CommitFest that's currently taking place (if any), please visit the
-<a href='/action/commitfest_view/inprogress'>CommitFest In Progress</a>.
+<a href='/action/commitfest_view/inprogress'>CommitFest In Progress</a>
+(<a href='/action/commitfest_activity/inprogress'>Activity Log</a>).
 These links are stable and always reference the open or in progress
 CommitFest, respectively, provided such a CommitFest exists.  (If there is no
 CommitFest in progress, the CommitFest In Progress link will reference the
 Open CommitFest instead.)  There is also a stable link for the
-<a href='/action/commitfest_view/previous'>Previous CommitFest</a>, meaning
+<a href='/action/commitfest_view/previous'>Previous CommitFest</a>
+(<a href='/action/commitfest_activity/previous'>Activity Log</a>), meaning
 the most recent one that is now marked Closed.  Upcoming CommitFests
 (other than the one to which patches should be submitted) are marked
 as <b>Future</b>.</p>