* Fix all my errors from checking in before testing.

This commit is contained in:
Toshio Kuratomi 2008-02-15 10:37:00 -08:00
parent c5078b9ce9
commit 38373eb1aa

View file

@ -6,17 +6,17 @@ create trusted procedural language plpgsql
validator plpgsql_validator; validator plpgsql_validator;
CREATE SEQUENCE cert_seq; CREATE SEQUENCE cert_seq;
SELECT setval(cert_seq, 1); SELECT setval('cert_seq', 1);
CREATE SEQUENCE person_seq; CREATE SEQUENCE person_seq;
-- TODO: Set this to start where our last person_id is -- TODO: Set this to start where our last person_id is
SELECT setval('person_seq', XXXXXX); SELECT setval('person_seq', 100000);
CREATE SEQUENCE group_seq; CREATE SEQUENCE group_seq;
-- TODO: Set this to start where our last group_id is -- TODO: Set this to start where our last group_id is
SELECT setval('group_seq', XXXXX); SELECT setval('group_seq', 100000);
CREATE TABLE person ( CREATE TABLE people (
id INTEGER PRIMARY KEY NOT NULL DEFAULT nextval('person_seq'), id INTEGER PRIMARY KEY NOT NULL DEFAULT nextval('person_seq'),
username VARCHAR(32) UNIQUE NOT NULL, username VARCHAR(32) UNIQUE NOT NULL,
human_name TEXT NOT NULL, human_name TEXT NOT NULL,
@ -32,7 +32,7 @@ CREATE TABLE person (
telephone TEXT, telephone TEXT,
facsimile TEXT, facsimile TEXT,
affiliation TEXT, affiliation TEXT,
certificate_serial integer nextval('cert_seq'), certificate_serial integer default nextval('cert_seq'),
creation TIMESTAMP DEFAULT NOW(), creation TIMESTAMP DEFAULT NOW(),
approval_status TEXT DEFAULT 'unapproved', approval_status TEXT DEFAULT 'unapproved',
internal_comments TEXT, internal_comments TEXT,
@ -40,105 +40,105 @@ CREATE TABLE person (
last_seen TIMESTAMP DEFAULT NOW(), last_seen TIMESTAMP DEFAULT NOW(),
status TEXT, status TEXT,
status_change TIMESTAMP DEFAULT NOW(), status_change TIMESTAMP DEFAULT NOW(),
check status in ('active', 'vacation', 'inactive', 'pinged'), check (status in ('active', 'vacation', 'inactive', 'pinged')),
check gpg_key_id ~ '^[0-9A-F]{17}$' check (gpg_keyid ~ '^[0-9A-F]{17}$')
); );
CREATE TABLE configs ( CREATE TABLE configs (
id SERIAL PRIMARY KEY, id SERIAL PRIMARY KEY,
person_id integer references person(id), person_id integer references people(id),
application text not null, application text not null,
attribute text not null, attribute text not null,
-- The value should be a simple value or a json string. -- The value should be a simple value or a json string.
-- Please create more config keys rather than abusing this with -- Please create more config keys rather than abusing this with
-- large datastructures. -- large datastructures.
value text, value TEXT,
check application in ('asterisk', 'moin', 'myfedora') check (application in ('asterisk', 'moin', 'myfedora'))
); );
CREATE TABLE group ( CREATE TABLE groups (
id INTEGER PRIMARY KEY NOT NULL DEFAULT nextval('group_seq'), id INTEGER PRIMARY KEY NOT NULL DEFAULT nextval('group_seq'),
name VARCHAR(32) UNIQUE NOT NULL, name VARCHAR(32) UNIQUE NOT NULL,
owner_id INTEGER NOT NULL REFERENCES person (id), owner_id INTEGER NOT NULL REFERENCES people(id),
group_type VARCHAR(16), group_type VARCHAR(16),
needs_sponsor INTEGER DEFAULT 0, needs_sponsor INTEGER DEFAULT 0,
user_can_remove INTEGER DEFAULT 1, user_can_remove INTEGER DEFAULT 1,
prerequisite_id INTEGER REFERENCES project_group (id) prerequisite_id INTEGER REFERENCES groups(id),
joinmsg TEXT NULL DEFAULT '', joinmsg TEXT NULL DEFAULT '',
check group_type in ('bugzilla','cvs', 'bzr', 'git', 'hg', 'mtn', check (group_type in ('bugzilla','cvs', 'bzr', 'git', 'hg', 'mtn',
'svn', 'shell', 'torrent', 'tracker', 'tracking', 'user') 'svn', 'shell', 'torrent', 'tracker', 'tracking', 'user'))
); );
create table person_email ( create table person_emails (
email text not null unique, email text not null unique,
group_id references person(id) not null, person_id integer references people(id) not null,
purpose text not null,
primary key (person_id, email),
check (purpose in ('bugzilla', 'primary', 'cla')),
check (email ~ '^[a-zA-Z0-9.]@[a-zA-Z0-9.][.][a-zA-Z]$'),
unique (person_id, purpose)
);
create table group_emails (
email text not null unique,
group_id integer references groups(id) not null,
purpose text not null, purpose text not null,
primary key (group_id, email), primary key (group_id, email),
check purpose in ('bugzilla', 'primary', 'cla'), check (purpose in ('bugzilla', 'primary', 'cla')),
check email ~ (^[a-zA-Z0-9.]@[a-zA-Z0-9.]\.[a-zA-Z]$),
unique (group_id, purpose) unique (group_id, purpose)
); );
create table group_email ( CREATE TABLE group_roles (
email text not null unique, member_id INTEGER NOT NULL REFERENCES groups(id),
group_id references group(id) not null, group_id INTEGER NOT NULL REFERENCES groups(id),
purpose text not null,
primary key (group_id, email),
check purpose in ('bugzilla', 'primary', 'cla'),
unique (group_id, purpose)
);
CREATE TABLE group_role (
member_id INTEGER NOT NULL REFERENCES group(id),
group_id INTEGER NOT NULL REFERENCES group(id),
role_type text NOT NULL, role_type text NOT NULL,
role_status text DEFAULT 'unapproved', role_status text DEFAULT 'unapproved',
internal_comments text, internal_comments text,
sponsor_id INTEGER REFERENCES person(id), sponsor_id INTEGER REFERENCES people(id),
creation TIMESTAMP DEFAULT NOW(), creation TIMESTAMP DEFAULT NOW(),
approval TIMESTAMP DEFAULT NOW(), approval TIMESTAMP DEFAULT NOW(),
UNIQUE (member_id, group_id), UNIQUE (member_id, group_id),
check role_status in ('approved', 'unapproved'), check (role_status in ('approved', 'unapproved')),
check role_type in ('user', 'administrator', 'sponsor') check (role_type in ('user', 'administrator', 'sponsor'))
); );
CREATE TABLE person_role ( CREATE TABLE person_roles (
person_id INTEGER NOT NULL REFERENCES person (id), person_id INTEGER NOT NULL REFERENCES people(id),
group_id INTEGER NOT NULL REFERENCES group (id), group_id INTEGER NOT NULL REFERENCES groups(id),
-- role_type is something like "user", "administrator", etc. -- role_type is something like "user", "administrator", etc.
-- role_status tells us whether this has been approved or not -- role_status tells us whether this has been approved or not
role_type text NOT NULL, role_type text NOT NULL,
role_status text DEFAULT 'unapproved', role_status text DEFAULT 'unapproved',
internal_comments text, internal_comments text,
sponsor_id INTEGER REFERENCES person(id), sponsor_id INTEGER REFERENCES people(id),
creation TIMESTAMP DEFAULT NOW(), creation TIMESTAMP DEFAULT NOW(),
approval TIMESTAMP DEFAULT NOW(), approval TIMESTAMP DEFAULT NOW(),
UNIQUE (person_id, group_id), UNIQUE (person_id, group_id),
check role_status in ('approved', 'unapproved'), check (role_status in ('approved', 'unapproved')),
check role_type in ('user', 'administrator', 'sponsor') check (role_type in ('user', 'administrator', 'sponsor'))
); );
-- action r == remove -- action r == remove
-- action a == add -- action a == add
create table bugzilla_queue ( create table bugzilla_queue (
email text not null, email text not null,
project_group_id int references project_group(id) not null, group_id int references groups(id) not null,
person_id int references person(id) not null, person_id int references people(id) not null,
action char(1) not null, action char(1) not null,
primary key (email, project_group_id), primary key (email, group_id),
check (action ~ '[ar]') check (action ~ '[ar]')
); );
create or replace function bugzilla_sync() returns trigger AS $bz_sync$ create or replace function bugzilla_sync() returns trigger AS $bz_sync$
DECLARE DECLARE
newaction char(1); newaction char(1);
ROW role%ROWTYPE; ROW person_roles%ROWTYPE;
BEGIN BEGIN
if TG_OP = 'DELETE' then if TG_OP = 'DELETE' then
newaction:='r'; newaction:='r';
ROW := OLD; ROW := OLD;
else else
INSERT or UPDATE -- INSERT or UPDATE
ROW := NEW; ROW := NEW;
if NEW.role_status = 'approved' then if NEW.role_status = 'approved' then
newaction := 'a'; newaction := 'a';
@ -146,11 +146,11 @@ BEGIN
newaction := 'r'; newaction := 'r';
end if; end if;
end if; end if;
if ROW.project_group_id = id from project_group where name = 'fedorabugs' then if ROW.group_id = id from groups where name = 'fedorabugs' then
if b.email is not Null from bugzilla_queue as b, person as p where p.id = ROW.person_id and b.email = p.email then if b.email is not Null from bugzilla_queue as b, people as p where p.id = ROW.person_id and b.email = p.email then
update bugzilla_queue set action = newaction where email in (select email from person where id = ROW.person_id); update bugzilla_queue set action = newaction where email in (select email from people where id = ROW.person_id);
else else
insert into bugzilla_queue select p.email, ROW.project_group_id, ROW.person_id, newaction from person as p where p.id = ROW.person_id; insert into bugzilla_queue select p.email, ROW.group_id, ROW.person_id, newaction from people as p where p.id = ROW.person_id;
end if; end if;
end if; end if;
return ROW; return ROW;
@ -158,29 +158,29 @@ END;
$bz_sync$ language plpgsql; $bz_sync$ language plpgsql;
create trigger role_bugzilla_sync before update or insert or delete create trigger role_bugzilla_sync before update or insert or delete
on role on person_roles
for each row execute procedure bugzilla_sync(); for each row execute procedure bugzilla_sync();
create or replace function bugzilla_sync_email() returns trigger AS $bz_sync_e$ create or replace function bugzilla_sync_email() returns trigger AS $bz_sync_e$
BEGIN BEGIN
if OLD.email = NEW.email then if OLD.email = NEW.email then
We only care if the email has been changed -- We only care if the email has been changed
return NEW; return NEW;
end if; end if;
if p.id is not Null from person as p, role as r, project_group as g where p.id = OLD.id and g.name = 'fedorabugs' and r.role_status = 'approved' and r.project_group_id = g.id and r.person_id = p.id then if p.id is not Null from people as p, person_roles as r, groups as g where p.id = OLD.id and g.name = 'fedorabugs' and r.role_status = 'approved' and r.group_id = g.id and r.person_id = p.id then
Person belongs to the bugzilla changing group -- Person belongs to the bugzilla changing group
Remove old email -- Remove old email
if b.email is not Null from bugzilla_queue as b where b.email = OLD.email then if b.email is not Null from bugzilla_queue as b where b.email = OLD.email then
update bugzilla_queue set action = 'r' where email = OLD.email; update bugzilla_queue set action = 'r' where email = OLD.email;
else else
insert into bugzilla_queue (select OLD.email, cast(g.id as int), OLD.id, 'r' from project_group as g where g.name = 'fedorabugs' limit 1); insert into bugzilla_queue (select OLD.email, cast(g.id as int), OLD.id, 'r' from groups as g where g.name = 'fedorabugs' limit 1);
end if; end if;
Add new email -- Add new email
if b.email is not Null from bugzilla_queue as b where b.email = NEW.email then if b.email is not Null from bugzilla_queue as b where b.email = NEW.email then
update bugzilla_queue set action = 'a' where email = NEW.email; update bugzilla_queue set action = 'a' where email = NEW.email;
else else
insert into bugzilla_queue (select NEW.email, cast(g.id as int), NEW.id, 'a' from project_group as g where g.name = 'fedorabugs' limit 1); insert into bugzilla_queue (select NEW.email, cast(g.id as int), NEW.id, 'a' from groups as g where g.name = 'fedorabugs' limit 1);
end if; end if;
end if; end if;
return NEW; return NEW;
@ -188,7 +188,7 @@ END;
$bz_sync_e$ language plpgsql; $bz_sync_e$ language plpgsql;
create trigger email_bugzilla_sync before update create trigger email_bugzilla_sync before update
on person on people
for each row execute procedure bugzilla_sync_email(); for each row execute procedure bugzilla_sync_email();
GRANT ALL ON TABLE person, project_group, role, id_seq, bugzilla_queue TO GROUP fedora; GRANT ALL ON TABLE people, groups, person_roles, person_emails, group_roles, group_emails, bugzilla_queue, configs, cert_seq, person_seq, group_seq TO GROUP fedora;