2008-02-16 12:30:32 -08:00
-- Copyright © 2008 Red Hat, Inc. All rights reserved.
--
-- This copyrighted material is made available to anyone wishing to use, modify,
-- copy, or redistribute it subject to the terms and conditions of the GNU
-- General Public License v.2. This program is distributed in the hope that it
-- will be useful, but WITHOUT ANY WARRANTY expressed or implied, including the
-- implied warranties of MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.
-- See the GNU General Public License for more details. You should have
-- received a copy of the GNU General Public License along with this program;
-- if not, write to the Free Software Foundation, Inc., 51 Franklin Street,
-- Fifth Floor, Boston, MA 02110-1301, USA. Any Red Hat trademarks that are
-- incorporated in the source code or documentation are not subject to the GNU
-- General Public License and may only be used or replicated with the express
-- permission of Red Hat, Inc.
--
2008-02-19 16:07:46 -08:00
-- Author(s): Toshio Kuratomi <tkuratom@redhat.com>
-- Ricky Zhou <ricky@fedoraproject.org>
2008-02-25 16:11:12 -06:00
-- Mike McGrath <mmcgrath@redhat.com>
2008-02-16 12:30:32 -08:00
--
2008-02-14 20:06:29 -08:00
create database fas2 encoding = ' UTF8 ' ;
\ c fas2
2008-02-23 11:05:11 -08:00
create procedural language plpythonu
handler plpythonu_call_handler
validator plpythonu_validator ;
2008-02-14 20:06:29 -08:00
CREATE SEQUENCE person_seq ;
-- TODO: Set this to start where our last person_id is
2008-02-15 15:10:31 -08:00
SELECT setval ( ' person_seq ' , 1111 ) ;
2008-02-14 20:06:29 -08:00
2008-02-15 10:37:00 -08:00
CREATE TABLE people (
2008-02-16 12:10:44 -08:00
-- tg_user::user_id
2008-02-15 14:59:06 -08:00
id INTEGER PRIMARY KEY NOT NULL DEFAULT nextval ( ' person_seq ' ) ,
2008-02-16 12:10:44 -08:00
-- tg_user::user_name
2008-02-15 14:59:06 -08:00
username VARCHAR ( 32 ) UNIQUE NOT NULL ,
2008-02-16 12:10:44 -08:00
-- tg_user::display_name
2008-02-15 14:59:06 -08:00
human_name TEXT NOT NULL ,
-- TODO: Switch to this?
-- Also, app would be responsible for eliminating spaces and
-- uppercasing
-- gpg_fingerprint varchar(40),
2008-02-27 12:53:14 -05:00
gpg_keyid VARCHAR ( 64 ) ,
2008-02-15 14:59:06 -08:00
ssh_key TEXT ,
2008-02-16 12:10:44 -08:00
-- tg_user::password
2008-02-15 14:59:06 -08:00
password VARCHAR ( 127 ) NOT NULL ,
2008-02-19 16:07:46 -08:00
passwordtoken text null ,
2008-03-08 12:44:17 -08:00
password_changed TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
2008-03-11 16:28:45 -07:00
email TEXT not null unique ,
emailtoken TEXT ,
unverified_email TEXT ,
2008-02-15 14:59:06 -08:00
comments TEXT ,
postal_address TEXT ,
telephone TEXT ,
facsimile TEXT ,
affiliation TEXT ,
2008-02-19 16:07:46 -08:00
certificate_serial INTEGER DEFAULT 1 ,
2008-02-16 12:10:44 -08:00
-- tg_user::created
2008-03-02 23:06:33 -05:00
creation TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
2008-02-19 16:07:46 -08:00
- - approval_status TEXT DEFAULT ' unapproved ' ,
2008-02-15 14:59:06 -08:00
internal_comments TEXT ,
ircnick TEXT ,
2008-03-02 23:06:33 -05:00
last_seen TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
2008-03-05 11:22:30 -05:00
status TEXT DEFAULT ' active ' ,
2008-03-02 23:06:33 -05:00
status_change TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
2008-02-19 16:07:46 -08:00
locale TEXT not null DEFAULT ' C ' ,
timezone TEXT null DEFAULT ' UTC ' ,
latitude numeric ,
longitude numeric ,
2008-02-27 12:53:14 -05:00
check ( status in ( ' active ' , ' vacation ' , ' inactive ' , ' pinged ' ) )
- - check ( gpg_keyid ~ ' ^[0-9A-F]{17}$ ' )
2008-02-14 20:06:29 -08:00
) ;
2008-02-23 11:33:32 -08:00
create index people_status_idx on people ( status ) ;
cluster people_status_idx on people ;
2008-02-14 20:06:29 -08:00
CREATE TABLE configs (
2008-02-15 14:59:06 -08:00
id SERIAL PRIMARY KEY ,
person_id integer references people ( id ) ,
2008-02-15 15:10:31 -08:00
application TEXT not null ,
attribute TEXT not null ,
2008-02-15 14:59:06 -08:00
-- The value should be a simple value or a json string.
-- Please create more config keys rather than abusing this with
-- large datastructures.
value TEXT ,
2008-02-19 16:07:46 -08:00
check ( application in ( ' asterisk ' , ' moin ' , ' myfedora ' , ' openid ' ) )
-- Might end up removing openid, depending on how far we take the provider
2008-02-14 20:06:29 -08:00
) ;
2008-02-23 12:10:22 -08:00
create index configs_person_id_idx on configs ( person_id ) ;
create index configs_application_idx on configs ( application ) ;
cluster configs_person_id_idx on configs ;
2008-02-15 10:37:00 -08:00
CREATE TABLE groups (
2008-02-16 12:10:44 -08:00
-- tg_group::group_id
2008-02-27 14:18:52 -08:00
id INTEGER PRIMARY KEY NOT NULL DEFAULT nextval ( ' person_seq ' ) ,
2008-02-16 12:10:44 -08:00
-- tg_group::group_name
2008-02-15 14:59:06 -08:00
name VARCHAR ( 32 ) UNIQUE NOT NULL ,
2008-02-16 12:10:44 -08:00
-- tg_group::display_name
display_name TEXT ,
2008-03-11 16:28:45 -07:00
-- Unlike users, groups can share email addresses
2008-03-11 19:29:15 -05:00
email TEXT ,
2008-03-11 16:28:45 -07:00
emailtoken TEXT ,
unverified_email TEXT ,
2008-02-15 14:59:06 -08:00
owner_id INTEGER NOT NULL REFERENCES people ( id ) ,
group_type VARCHAR ( 16 ) ,
2008-02-25 15:29:37 -06:00
needs_sponsor BOOLEAN DEFAULT FALSE ,
user_can_remove BOOLEAN DEFAULT TRUE ,
2008-02-15 14:54:27 -08:00
prerequisite_id INTEGER REFERENCES groups ( id ) ,
joinmsg TEXT NULL DEFAULT ' ' ,
2008-02-16 12:10:44 -08:00
-- tg_group::created
2008-03-02 23:06:33 -05:00
creation TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
2008-03-07 15:24:08 -05:00
check ( group_type in ( ' system ' , ' bugzilla ' , ' cvs ' , ' bzr ' , ' git ' , ' hg ' , ' mtn ' ,
2008-02-15 15:10:31 -08:00
' svn ' , ' shell ' , ' torrent ' , ' tracker ' , ' tracking ' , ' user ' ) )
2008-02-14 20:06:29 -08:00
) ;
2008-02-23 12:10:22 -08:00
create index groups_group_type_idx on groups ( group_type ) ;
2008-03-11 16:28:45 -07:00
create index groups_email_idx on groups ( email ) ;
2008-02-23 12:10:22 -08:00
cluster groups_group_type_idx on groups ;
2008-02-16 12:20:51 -08:00
CREATE TABLE person_roles (
person_id INTEGER NOT NULL REFERENCES people ( id ) ,
group_id INTEGER NOT NULL REFERENCES groups ( id ) ,
-- role_type is something like "user", "administrator", etc.
-- role_status tells us whether this has been approved or not
role_type text NOT NULL ,
role_status text DEFAULT ' unapproved ' ,
internal_comments text ,
sponsor_id INTEGER REFERENCES people ( id ) ,
2008-03-02 23:06:33 -05:00
creation TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
approval TIMESTAMP WITH TIME ZONE DEFAULT NULL ,
2008-02-19 11:52:46 -08:00
primary key ( person_id , group_id ) ,
2008-02-16 12:20:51 -08:00
check ( role_status in ( ' approved ' , ' unapproved ' ) ) ,
check ( role_type in ( ' user ' , ' administrator ' , ' sponsor ' ) )
) ;
2008-02-23 12:10:22 -08:00
create index person_roles_person_id_idx on person_roles ( person_id ) ;
create index person_roles_group_id_idx on person_roles ( group_id ) ;
-- We could cluster on either person or group. The choice of group is because
-- groups are larger and therefore will take more memory if guessed wrong.
-- Open to reevaluation.
cluster person_roles_group_id_idx on person_roles ;
2008-02-15 10:37:00 -08:00
CREATE TABLE group_roles (
2008-02-15 14:59:06 -08:00
member_id INTEGER NOT NULL REFERENCES groups ( id ) ,
group_id INTEGER NOT NULL REFERENCES groups ( id ) ,
role_type text NOT NULL ,
role_status text DEFAULT ' unapproved ' ,
internal_comments text ,
sponsor_id INTEGER REFERENCES people ( id ) ,
2008-03-02 23:06:33 -05:00
creation TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
approval TIMESTAMP WITH TIME ZONE DEFAULT NOW ( ) ,
2008-02-19 11:52:46 -08:00
primary key ( member_id , group_id ) ,
2008-02-15 14:59:06 -08:00
check ( role_status in ( ' approved ' , ' unapproved ' ) ) ,
check ( role_type in ( ' user ' , ' administrator ' , ' sponsor ' ) )
2008-02-14 20:06:29 -08:00
) ;
2008-02-23 12:10:22 -08:00
create index group_roles_member_id_idx on group_roles ( member_id ) ;
create index group_roles_group_id_idx on group_roles ( group_id ) ;
-- We could cluster on either member or group. The choice of member is
-- because member pages will be viewed more frequently.
-- Open to reevaluation.
cluster group_roles_group_id_idx on group_roles ;
2008-02-14 20:06:29 -08:00
-- action r == remove
-- action a == add
create table bugzilla_queue (
2008-02-15 14:54:27 -08:00
email text not null ,
2008-02-15 15:10:31 -08:00
group_id INTEGER references groups ( id ) not null ,
person_id INTEGER references people ( id ) not null ,
action CHAR ( 1 ) not null ,
2008-02-15 14:54:27 -08:00
primary key ( email , group_id ) ,
check ( action ~ ' [ar] ' )
2008-02-14 20:06:29 -08:00
) ;
2008-02-21 15:04:19 -08:00
-- Log changes to the account system
create table log (
id serial primary key ,
2008-02-21 17:03:44 -08:00
author_id INTEGER references people ( id ) not null ,
2008-03-02 23:06:33 -05:00
changetime TIMESTAMP WITH TIME ZONE default NOW ( ) ,
2008-02-21 15:04:19 -08:00
description TEXT
) ;
2008-02-23 12:10:22 -08:00
create index log_changetime_idx on log ( changetime ) ;
cluster log_changetime_idx on log ;
2008-02-29 15:27:03 -08:00
--
-- This table allows certain services to be restricted by hostname/ip/person.
--
-- Any time a request for a restricted action is requested, the FAS server
-- consults this table to see if the user@(hostname/ip) is allowed to access
-- the resource. If approved is true, the request is granted. If false or
-- null, the request is denied.
--
-- New records are created when a request is first made by a specific
-- username@(hostname/id)
--
2008-02-29 15:36:24 -08:00
create table requests (
2008-02-29 23:40:33 +00:00
id serial primary key ,
2008-02-29 15:27:03 -08:00
person_id INTEGER not null references people ( id ) ,
hostname TEXT not null ,
ip TEXT not null ,
action TEXT not null default ' trust_all ' ,
2008-03-02 23:06:33 -05:00
last_request TIMESTAMP WITH TIME ZONE default now ( ) not null ,
2008-02-29 15:27:03 -08:00
approved boolean ,
unique ( person_id , hostname , ip , action )
) ;
2008-02-29 23:40:33 +00:00
create index requests_last_request_idx on requests ( last_request ) ;
2008-02-29 15:36:24 -08:00
create index hostname_idx on requests ( hostname ) ;
create index ip_idx on requests ( ip ) ;
create index person_id_idx on requests ( person_id ) ;
2008-02-29 23:40:33 +00:00
cluster requests_last_request_idx on requests ;
2008-02-29 15:27:03 -08:00
2008-02-16 12:10:44 -08:00
--
-- turbogears session tables
--
create table visit (
visit_key CHAR ( 40 ) primary key ,
2008-03-02 23:06:33 -05:00
created TIMESTAMP WITH TIME ZONE not null default now ( ) ,
expiry TIMESTAMP WITH TIME ZONE
2008-02-16 12:10:44 -08:00
) ;
2008-02-23 12:10:22 -08:00
create index visit_expiry_idx on visit ( expiry ) ;
cluster visit_expiry_idx on visit ;
2008-02-16 12:10:44 -08:00
create table visit_identity (
visit_key CHAR ( 40 ) primary key references visit ( visit_key ) ,
user_id INTEGER references people ( id )
) ;
2008-02-23 11:05:11 -08:00
--
2008-03-11 17:01:51 -07:00
-- When the fedorabugs role is updated for a person, add them to bugzilla queue.
2008-02-23 11:05:11 -08:00
--
2008-03-11 08:01:36 -07:00
create or replace function bugzilla_sync ( ) returns trigger as $ bz_sync $
# Decide which row we are operating on and the action to take
if TD [ ' event ' ] = = ' DELETE ' :
# 'r' for removing an entry from bugzilla
newaction = ' r '
row = TD [ ' old ' ]
else :
# insert or update
row = TD [ ' new ' ]
if row [ ' role_status ' ] = = ' approved ' :
# approved so add an entry to bugzilla
newaction = ' a '
else :
# no longer approved so remove the entry from bugzilla
newaction = ' r '
# Get the group id for fedorabugs
result = plpy . execute ( " select id from groups where name = 'fedorabugs' " , 1 )
if not result :
# Danger Will Robinson! A basic FAS group does not exist!
plpy . error ( ' Basic FAS group fedorabugs does not exist ' )
# If this is not a fedorabugs role, no change needed
if row [ ' group_id ' ] ! = result [ 0 ] [ ' id ' ] :
return None
# Retrieve the bugzilla email address
2008-03-11 17:05:54 -07:00
### FIXME: Once we implement it, we will want to add a check for an email
2008-03-11 17:01:51 -07:00
# address in configs::application='bugzilla',person_id=person_id,
# attribute='login'
plan = plpy . prepare ( " select email from people where id = $1 " , ( ' int4 ' , ) )
2008-03-11 15:04:44 -07:00
result = plpy . execute ( plan , ( row [ ' person_id ' ] , ) )
2008-03-11 17:01:51 -07:00
if not result :
# No email address so nothing can be done
return None
email = result [ 0 ] [ ' email ' ]
2008-03-11 08:01:36 -07:00
# If there is already a row in bugzilla_queue update, otherwise insert
plan = plpy . prepare ( " select email from bugzilla_queue where email = $1 " ,
( ' text ' , ) )
result = plpy . execute ( plan , ( email , ) , 1 )
if result :
plan = plpy . prepare ( " update bugzilla_queue set action = $1 "
" where email = $2 " , ( ' char ' , ' text ' ) )
plpy . execute ( plan , ( newaction , email ) )
else :
plan = plpy . prepare ( " insert into bugzilla_queue (email, group_id "
" , person_id, action) values ($1, $2, $3, $4) " ,
2008-03-11 15:04:44 -07:00
( ' text ' , ' int4 ' , ' int4 ' , ' char ' ) )
2008-03-11 08:01:36 -07:00
plpy . execute ( plan , ( email , row [ ' group_id ' ] , row [ ' person_id ' ] , newaction ) )
return None
$ bz_sync $ language plpythonu ;
create trigger role_bugzilla_sync before update or insert or delete
on person_roles
for each row execute procedure bugzilla_sync ( ) ;
2008-02-14 20:06:29 -08:00
2008-02-23 11:05:11 -08:00
--
-- When an email address changes, check whether it needs to be changed in
-- bugzilla as well.
--
2008-03-11 17:53:29 -07:00
create or replace function bugzilla_sync_email ( ) returns trigger AS $ bz_sync_e $
2008-03-11 18:19:13 -07:00
if TD [ ' old ' ] [ ' email ' ] = = TD [ ' new ' ] [ ' email ' ] :
2008-03-11 17:53:29 -07:00
# We only care if the email has been changed
return None ;
# Get the group id for fedorabugs
result = plpy . execute ( " select id from groups where name = 'fedorabugs' " , 1 )
if not result :
# Danger Will Robinson! A basic FAS group does not exist!
plpy . error ( ' Basic FAS group fedorabugs does not exist ' )
fedorabugsId = result [ 0 ] [ ' id ' ]
plan = plpy . prepare ( " select person_id from person_roles where "
2008-03-11 18:19:13 -07:00
" role_status = 'approved' and group_id = $1 "
" and person_id = $2 " , ( ' int4 ' , ' int4 ' ) )
2008-03-11 17:53:29 -07:00
result = plpy . execute ( plan , ( fedorabugsId , TD [ ' old ' ] [ ' id ' ] ) , 1 )
if not result :
# We only care if Person belongs to fedorabugs
return None ;
# Remove the old Email and add the new one
changes = [ ]
changes . append ( ( TD [ ' old ' ] [ ' email ' ] , fedorabugsId , TD [ ' old ' ] [ ' id ' ] , ' r ' ) )
changes . append ( ( TD [ ' new ' ] [ ' email ' ] , fedorabugsId , TD [ ' new ' ] [ ' id ' ] , ' a ' ) )
for change in changes :
# Check if we already have a pending change
plan = plpy . prepare ( " select b.email from bugzilla_queue as b where "
" b.email = $1 " , ( ' text ' , ) )
result = plpy . execute ( plan , ( change [ 0 ] , ) , 1 )
if result :
# Yes, update that change
plan = plpy . prepare ( " update bugzilla_queue set email = $1, "
" group_id = $2, person_id = $3, action = $4 where "
2008-03-11 18:19:13 -07:00
" email = $1 " , ( ' text ' , ' int4 ' , ' int4 ' , ' char ' ) )
2008-03-11 17:53:29 -07:00
plpy . execute ( plan , change )
else :
# No, add a new change
plan = plpy . prepare ( " insert into bugzilla_queue "
" (email, group_id, person_id, action) "
" values ($1, $2, $3, $4) " , ( ' text ' , ' int4 ' , ' int4 ' , ' char ' ) )
plpy . execute ( plan , change )
return None
2008-03-11 17:59:16 -07:00
$ bz_sync_e $ language plpythonu ;
2008-03-11 17:53:29 -07:00
create trigger email_bugzilla_sync before update on people
for each row execute procedure bugzilla_sync_email ( ) ;
2008-02-14 20:06:29 -08:00
2008-02-16 12:20:51 -08:00
-- For Fas to connect to the database
2008-03-11 19:29:15 -05:00
GRANT ALL ON TABLE people , groups , person_roles , group_roles , bugzilla_queue , configs , person_seq , visit , visit_identity , log , log_id_seq TO GROUP fedora ;
2008-02-25 14:09:13 -06:00
2008-02-28 14:07:14 -06:00
-- Create default admin user - Default Password "admin"
2008-03-11 18:53:00 -05:00
INSERT INTO people ( id , username , human_name , password , email ) VALUES ( 100001 , ' admin ' , ' Admin User ' , ' $1$djFfnacd$b6NFqFlac743Lb4sKWXj4/ ' , ' root@localhost ' ) ;
2008-02-25 14:09:13 -06:00
-- Create default groups and populate
2008-03-12 18:18:12 -04:00
INSERT INTO groups ( id , name , display_name , owner_id , group_type ) VALUES ( 100002 , ' cla_done ' , ' CLA Done Group ' , ( SELECT id from people where username = ' admin ' ) , ' tracking ' ) ;
INSERT INTO groups ( id , name , display_name , owner_id , group_type ) VALUES ( 101441 , ' cla_fedora ' , ' Fedora CLA Group ' , ( SELECT id from people where username = ' admin ' ) , ' tracking ' ) ;
2008-03-07 16:20:17 -06:00
INSERT INTO groups ( id , name , display_name , owner_id , group_type ) VALUES ( 100006 , ' accounts ' , ' Account System Admins ' , ( SELECT id from people where username = ' admin ' ) , ' tracking ' ) ;
INSERT INTO groups ( id , name , display_name , owner_id , group_type ) VALUES ( 100148 , ' fedorabugs ' , ' Fedora Bugs Group ' , ( SELECT id from people where username = ' admin ' ) , ' tracking ' ) ;
2008-03-07 11:56:13 -06:00
INSERT INTO groups ( name , display_name , owner_id , group_type ) VALUES ( ' fas-system ' , ' System users allowed to get password and key information ' , ( SELECT id from people where username = ' admin ' ) , ' system ' ) ;
2008-03-07 11:55:39 -06:00
2008-02-25 14:29:52 -06:00
INSERT INTO person_roles ( person_id , group_id , role_type , role_status , internal_comments , sponsor_id ) VALUES ( ( SELECT id from people where username = ' admin ' ) , ( select id from groups where name = ' accounts ' ) , ' administrator ' , ' approved ' , ' created at install time ' , ( SELECT id from people where username = ' admin ' ) ) ;