* Primary key for each table FOO is now consistently FOO_id rather than just ID.
* Fields which are taken from mail headers have a _hdr suffix.
* Fields which are taken raw from user input have a _raw suffix.
An existing DB can be upgraded with:
8<-------------------------------------------------
BEGIN TRANSACTION;
ALTER TABLE messages RENAME TO tmp_messages;
create table messages (
message_id integer primary key autoincrement,
msgid_hdr_raw varchar not null unique,
present bool default false, -- following fields valid iff true
inserttime integer default 0,
-- XXX enum "normal", "control", "control-reply"
msgtype char(16) default "normal", -- control / control-reply
-- Selected header values
msgdate_hdr_raw varchar,
msgfrom_hdr_raw varchar,
msgto_hdr_raw varchar,
msgcc_hdr_raw varchar,
subject_hdr_raw varchar
);
INSERT INTO messages(message_id,msgid_hdr_raw,present,inserttime,msgtype,msgdate_hdr_raw,msgfrom_hdr_raw,msgto_hdr_raw,msgcc_hdr_raw,subject_hdr_raw)
SELECT id, messageid, present, inserttime, msgtype, msgdate, msgfrom, msgto, msgcc, subject
FROM tmp_messages;
DROP TABLE tmp_messages;
ALTER TABLE refs RENAME TO tmp_refs;
create table refs (
ref_id integer primary key autoincrement,
parent_id integer references messages ( message_id ),
child_id integer references messages ( message_id )
);
INSERT INTO refs(ref_id, parent_id, child_id)
SELECT id,parentid,childid
FROM tmp_refs;
DROP TABLE tmp_refs;
ALTER TABLE bugs RENAME TO tmp_bugs;
create table bugs (
bug_id integer primary key autoincrement,
title_raw varchar,
creationdate integer,
lastchangedate integer,
owner_raw varchar,
severity varchar,
open bool default true
-- xxx other fields
-- tags? component?
-- affected branches?
);
INSERT INTO bugs(bug_id,title_raw,creationdate,lastchangedate,owner_raw,severity,open)
SELECT id,title,creationdate, lastchangedate,owner,severity,open
FROM tmp_bugs;
DROP TABLE tmp_bugs;
ALTER TABLE bug2message RENAME TO tmp_bug2message;
create table bug2message (
bug2message_id integer primary key autoincrement,
include bool default true, -- if true then graft, if false then exclude
bug_id integer not null references bugs ( bug_id ),
message_id integer not null references messages ( message_id )
);
INSERT INTO bug2message(bug2message_id,include,bug_id,message_id)
SELECT id,include,bugid,messageid
FROM tmp_bug2message;
DROP TABLE tmp_bug2message;
COMMIT;
8<-------------------------------------------------
use Emesinae::Message;
use Emesinae::Common;
-my $SELECT_FIELDS = "id,title,creationdate,lastchangedate,owner,severity,open";
+my $SELECT_FIELDS = "bug_id,title_raw,creationdate,lastchangedate,owner_raw,severity,open";
sub new {
my $class = shift;
}
elsif ( $args{ID} ) {
my $sth = $dbh->prepare( "
- SELECT $SELECT_FIELDS FROM bugs WHERE id = ?
+ SELECT $SELECT_FIELDS FROM bugs WHERE bug_id = ?
" );
$sth->execute( $args{ID} ) or die "Failed to lookup bug";
$row = $sth->fetchrow_arrayref;
my $sth = $dbh->prepare(
q{
INSERT
- INTO bugs (title,creationdate,lastchangedate,owner,severity)
+ INTO bugs (title_raw,creationdate,lastchangedate,owner_raw,severity)
VALUES (?,strftime('%s', 'now'),strftime('%s', 'now'),?,?)
}
);
my $sth = $self->{dbh}->prepare( "
UPDATE bugs
SET $field=?,lastchangedate=strftime('%s', 'now')
- WHERE id = ?
+ WHERE bug_id = ?
" );
$sth->execute( $value, $self->{id} ) or die "Setting $field";
$sth->finish;
my $self = shift;
my $title = shift;
- $self->_set("title", $title);
+ $self->_set("title_raw", $title);
}
sub set_owner {
my $self = shift;
my $owner = shift;
- $self->_set("owner", $owner);
+ $self->_set("owner_raw", $owner);
}
sub set_severity {
q{
UPDATE bugs
SET open=?
- WHERE id = ?
+ WHERE bug_id = ?
}
);
my $sth = $self->{dbh}->prepare(
q{
INSERT
- INTO bug2message (include,bugid,messageid)
+ INTO bug2message (include,bug_id,message_id)
VALUES (?,?,?)
}
);
my $sth = $self->{dbh}->prepare(
q{
- SELECT include,messageid FROM bug2message WHERE bugid = ? ORDER BY id
+ SELECT include,message_id FROM bug2message WHERE bug_id = ? ORDER BY bug2message_id
}
);
}
my $select = "SELECT $SELECT_FIELDS FROM bugs ";
$select .= "WHERE " . join( " AND ", map { qq{($_)} } @where ) if @where;
- $select .= " ORDER BY id";
+ $select .= " ORDER BY bug_id";
#print "<p>$select</p>";
my $sth = $dbh->prepare($select);
my $sth = $dbh->prepare(
q{
- SELECT messageid,present,inserttime,msgtype,msgdate,msgfrom,msgto,msgcc,subject
+ SELECT msgid_hdr_raw,present,inserttime,msgtype,msgdate_hdr_raw,msgfrom_hdr_raw,msgto_hdr_raw,msgcc_hdr_raw,subject_hdr_raw
FROM messages
- WHERE id = ?
+ WHERE message_id = ?
}
);
my $sth = $dbh->prepare(
q{
- SELECT id,present,inserttime,msgtype,msgdate,msgfrom,msgto,msgcc,subject
+ SELECT message_id,present,inserttime,msgtype,msgdate_hdr_raw,msgfrom_hdr_raw,msgto_hdr_raw,msgcc_hdr_raw,subject_hdr_raw
FROM messages
- WHERE messageid = ?
+ WHERE msgid_hdr_raw = ?
}
);
elsif ( $args{Insert} ) {
my $sth = $dbh->prepare(
q{
- INSERT into messages (messageid) VALUES (?)
+ INSERT into messages (msgid_hdr_raw) VALUES (?)
}
);
q{
UPDATE messages
SET msgtype=?2
- WHERE id = ?1}
+ WHERE message_id = ?1}
) or die "prepare type update";
$sth->execute( $self->{id}, $type ) or die "execute type update";
$sth->finish or die "finish type update";
q{
UPDATE messages
SET present="true",
- subject=?2,
+ subject_hdr_raw=?2,
inserttime=strftime('%s', 'now'),
- msgdate=?3,
- msgfrom=?4,
- msgto=?5,
- msgcc=?6
- WHERE id = ?1}
+ msgdate_hdr_raw=?3,
+ msgfrom_hdr_raw=?4,
+ msgto_hdr_raw=?5,
+ msgcc_hdr_raw=?6
+ WHERE message_id = ?1}
);
$sth->execute(
$self->{id},
Emesinae::Message->lookup_msgid( $self->{dbh}, $irt, Insert => 1 );
$sth =
$self->{dbh}
- ->prepare(q{INSERT INTO refs (parentid,childid) VALUES (?1,?2)});
+ ->prepare(q{INSERT INTO refs (parent_id,child_id) VALUES (?1,?2)});
$sth->execute( $refto->{id}, $self->{id} );
}
Emesinae::Message->lookup_msgid( $self->{dbh}, $r, Insert => 1 );
$sth =
$self->{dbh}
- ->prepare(q{INSERT INTO refs (parentid,childid) VALUES (?1,?2)});
+ ->prepare(q{INSERT INTO refs (parent_id,child_id) VALUES (?1,?2)});
$sth->execute( $refto->{id}, $self->{id} );
}
}
my ( $self, $inc, $refs ) = @_;
my $sth =
- $self->{dbh}->prepare(q{SELECT childid FROM refs WHERE parentid = ?});
+ $self->{dbh}->prepare(q{SELECT child_id FROM refs WHERE parent_id = ?});
$sth->execute( $self->{id} ) or die "Lookup subthread";
while ( defined( my $r = $sth->fetch ) ) {
- return individual parts
database:
- - suffix fields containing raw (and therefore potentially dangerous)
- information e.g. from mail headers with something to flag them.
- - rename "id" fields with table prefix for clarity, e.g. message_id, bug_id etc.
- Add "created-by" and "reported-by" fields to bug, allow owner to be NULL by
default.
- Refactor email addresses into their own table and create references instead
create table messages (
- id integer primary key autoincrement,
- messageid varchar not null unique,
+ message_id integer primary key autoincrement,
+ msgid_hdr_raw varchar not null unique,
present bool default false, -- following fields valid iff true
inserttime integer default 0,
msgtype char(16) default "normal", -- control / control-reply
-- Selected header values
- msgdate varchar,
- msgfrom varchar,
- msgto varchar,
- msgcc varchar,
- subject varchar
+ msgdate_hdr_raw varchar,
+ msgfrom_hdr_raw varchar,
+ msgto_hdr_raw varchar,
+ msgcc_hdr_raw varchar,
+ subject_hdr_raw varchar
);
--
create table refs (
- id integer primary key autoincrement,
- parentid integer references messages ( id ),
- childid integer references messages ( id )
+ ref_id integer primary key autoincrement,
+ parent_id integer references messages ( message_id ),
+ child_id integer references messages ( message_id )
);
--create table components {
--insert into components (name) VALUES "kernel/linux";
create table bugs (
- id integer primary key autoincrement,
- title varchar,
+ bug_id integer primary key autoincrement,
+ title_raw varchar,
creationdate integer,
lastchangedate integer,
- owner varchar,
+ owner_raw varchar,
severity varchar,
open bool default true
-- xxx other fields
);
create table bug2message (
- id integer primary key autoincrement,
+ bug2message_id integer primary key autoincrement,
include bool default true, -- if true then graft, if false then exclude
- bugid integer not null references bugs ( id ),
- messageid integer not null references messages ( id )
+ bug_id integer not null references bugs ( bug_id ),
+ message_id integer not null references messages ( message_id )
);