--- /dev/null
+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;
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);
$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
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'});
# 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'}) {