-- LegacyWorlds Beta 6 -- PostgreSQL database scripts -- -- Tables that support the bug tracking system -- -- Copyright(C) 2004-2010, DeepClone Development -- -------------------------------------------------------- -- -- Bug event types -- CREATE TYPE bug_event_type AS ENUM( 'INIT' , 'MERGE' , 'STATUS' , 'COMMENT' , 'VISIBILITY' ); -- -- Bug statuses -- CREATE TYPE bug_status_type AS ENUM( 'OPEN' , 'NOT_A_BUG' , 'WONT_FIX' , 'RESOLVED' ); -- -- Bug submitters -- CREATE TABLE bugs.submitters ( submitter_id BIGSERIAL PRIMARY KEY , is_admin BOOLEAN NOT NULL , name VARCHAR( 64 ) NOT NULL ); CREATE INDEX idx_submitters_isadmin ON bugs.submitters ( is_admin ); -- -- Bug submitters - administrators -- CREATE TABLE bugs.admin_submitters( submitter_id BIGINT PRIMARY KEY , admin_id INT NOT NULL UNIQUE ); ALTER TABLE bugs.admin_submitters ADD CONSTRAINT fk_adminsubs_submitter FOREIGN KEY ( submitter_id ) REFERENCES bugs.submitters , ADD CONSTRAINT fk_adminsubs_admin FOREIGN KEY ( admin_id ) REFERENCES admin.administrators ON DELETE CASCADE; -- -- Bug submitters - users -- CREATE TABLE bugs.user_submitters( submitter_id BIGINT PRIMARY KEY , account_id INT NOT NULL UNIQUE ); ALTER TABLE bugs.user_submitters ADD CONSTRAINT fk_usersubs_submitter FOREIGN KEY ( submitter_id ) REFERENCES bugs.submitters , ADD CONSTRAINT fk_usersubs_account FOREIGN KEY ( account_id ) REFERENCES users.active_accounts ON DELETE CASCADE ON UPDATE CASCADE; -- -- Report groups -- CREATE TABLE bugs.groups( group_id BIGSERIAL PRIMARY KEY ); -- -- Report events - main table -- CREATE TABLE bugs.events( event_id BIGSERIAL PRIMARY KEY , group_id BIGINT NOT NULL , submitter_id BIGINT NOT NULL , e_type bug_event_type NOT NULL , t TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT now( ) ); CREATE INDEX idx_events_group ON bugs.events( group_id ); CREATE INDEX idx_events_submitter ON bugs.events( submitter_id ); CREATE INDEX idx_events_time ON bugs.events( t ); ALTER TABLE bugs.events ADD CONSTRAINT fk_events_group FOREIGN KEY ( group_id ) REFERENCES bugs.groups , ADD CONSTRAINT fk_events_submitter FOREIGN KEY ( submitter_id ) REFERENCES bugs.submitters; GRANT SELECT ON bugs.events TO :dbuser; -- -- Report events - initial reports -- CREATE TABLE bugs.initial_report_events( event_id BIGINT PRIMARY KEY , title VARCHAR( 128 ) NOT NULL , description TEXT NOT NULL ); ALTER TABLE bugs.initial_report_events ADD CONSTRAINT fk_initialreports_event FOREIGN KEY ( event_id ) REFERENCES bugs.events; -- -- Report events - mergers -- CREATE TABLE bugs.merge_events( event_id BIGINT PRIMARY KEY , initial_post_id BIGINT NOT NULL ); CREATE INDEX idx_mergers_initialpost ON bugs.merge_events( initial_post_id ); ALTER TABLE bugs.merge_events ADD CONSTRAINT fk_mergers_event FOREIGN KEY ( event_id ) REFERENCES bugs.events , ADD CONSTRAINT fk_mergers_initial FOREIGN KEY ( initial_post_id ) REFERENCES bugs.initial_report_events; -- -- Report events - status change -- CREATE TABLE bugs.status_change_events( event_id BIGINT PRIMARY KEY , status bug_status_type NOT NULL ); ALTER TABLE bugs.status_change_events ADD CONSTRAINT fk_statuschanges_event FOREIGN KEY ( event_id ) REFERENCES bugs.events; -- -- Report events - comments -- CREATE TABLE bugs.comment_events( event_id BIGINT PRIMARY KEY , comment TEXT NOT NULL , visible BOOLEAN NOT NULL ); ALTER TABLE bugs.comment_events ADD CONSTRAINT fk_comments_event FOREIGN KEY ( event_id ) REFERENCES bugs.events; -- -- Report events - visibility changes -- CREATE TABLE bugs.visibility_events( event_id BIGINT PRIMARY KEY , visible BOOLEAN NOT NULL ); ALTER TABLE bugs.visibility_events ADD CONSTRAINT fk_visibility_event FOREIGN KEY ( event_id ) REFERENCES bugs.events; -- -- Account status information submitted along with bug reports by players -- CREATE TABLE bugs.account_status_data( event_id BIGINT PRIMARY KEY , account_status TEXT ); ALTER TABLE bugs.account_status_data ADD CONSTRAINT fk_accountstatus_event FOREIGN KEY ( event_id ) REFERENCES bugs.initial_report_events; GRANT SELECT ON bugs.account_status_data TO :dbuser; -- -- View status - administrators -- CREATE TABLE bugs.admin_view_status( group_id BIGINT NOT NULL , admin_id INT NOT NULL , last_view TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT now( ) , PRIMARY KEY( group_id , admin_id ) ); CREATE INDEX idx_adminview_admin ON bugs.admin_view_status ( admin_id ); CREATE INDEX idx_adminview_lastview ON bugs.admin_view_status ( last_view ); ALTER TABLE bugs.admin_view_status ADD CONSTRAINT fk_adminview_group FOREIGN KEY ( group_id ) REFERENCES bugs.groups ON DELETE CASCADE , ADD CONSTRAINT fk_adminview_admin FOREIGN KEY ( admin_id ) REFERENCES admin.administrators; -- -- View status - players -- CREATE TABLE bugs.user_view_status( group_id BIGINT NOT NULL , user_id INT NOT NULL , last_view TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT now( ) , PRIMARY KEY( group_id , user_id ) ); CREATE INDEX idx_userview_user ON bugs.user_view_status ( user_id ); CREATE INDEX idx_userview_lastview ON bugs.user_view_status ( last_view ); ALTER TABLE bugs.user_view_status ADD CONSTRAINT fk_userview_group FOREIGN KEY ( group_id ) REFERENCES bugs.groups ON DELETE CASCADE , ADD CONSTRAINT fk_userview_user FOREIGN KEY ( user_id ) REFERENCES users.active_accounts ON DELETE CASCADE ON UPDATE CASCADE;