-- LegacyWorlds Beta 6 -- PostgreSQL database scripts -- -- Account tables -- -- Copyright(C) 2004-2010, DeepClone Development -- -------------------------------------------------------- -- -- Active account -- CREATE TABLE users.active_accounts( credentials_id INT NOT NULL PRIMARY KEY , vacation_credits INT NOT NULL CHECK( vacation_credits >= 0 ) ); ALTER TABLE users.active_accounts ADD CONSTRAINT fk_activeaccounts_creds FOREIGN KEY (credentials_id) REFERENCES users.credentials ON DELETE CASCADE ON UPDATE CASCADE; -- -- Vacation credits -- CREATE TABLE users.vacations( account_id INT NOT NULL PRIMARY KEY , since TIMESTAMP WITHOUT TIME ZONE NOT NULL , status processing_status NOT NULL ); CREATE INDEX idx_vacations_status ON users.vacations (since, status); ALTER TABLE users.vacations ADD CONSTRAINT fk_vacations_accounts FOREIGN KEY (account_id) REFERENCES users.active_accounts ON DELETE CASCADE ON UPDATE CASCADE; -- -- Preferences -- CREATE TABLE users.preferences( account_id INT NOT NULL , definition_id INT NOT NULL , pref_value TEXT NOT NULL , PRIMARY KEY (account_id,definition_id) ); CREATE INDEX idx_preferences_definition ON users.preferences( definition_id ); ALTER TABLE users.preferences ADD CONSTRAINT fk_preferences_accounts FOREIGN KEY (account_id) REFERENCES users.active_accounts ON DELETE CASCADE ON UPDATE CASCADE , ADD CONSTRAINT fk_preferences_definition FOREIGN KEY (definition_id) REFERENCES defs.preference_definitions ON DELETE CASCADE; -- -- Inactive accounts -- CREATE TABLE users.inactive_accounts( credentials_id INT NOT NULL PRIMARY KEY , since TIMESTAMP WITHOUT TIME ZONE NOT NULL , status processing_status NOT NULL ); CREATE INDEX idx_inactiveaccounts_status ON users.vacations (since, status); ALTER TABLE users.inactive_accounts ADD CONSTRAINT fk_inactiveaccounts_creds FOREIGN KEY (credentials_id) REFERENCES users.credentials ON DELETE CASCADE ON UPDATE CASCADE; -- -- Account de-activation reasons -- CREATE TABLE users.reasons( account_id INT NOT NULL PRIMARY KEY , reason TEXT NOT NULL ); ALTER TABLE users.reasons ADD CONSTRAINT fk_reasons_account FOREIGN KEY (account_id) REFERENCES users.inactive_accounts ON DELETE CASCADE ON UPDATE CASCADE; -- -- Bans -- CREATE TABLE users.bans( account_id INT NOT NULL PRIMARY KEY , ban_id INT NOT NULL ); CREATE UNIQUE INDEX idx_bans_banrequest ON users.bans (ban_id); ALTER TABLE users.bans ADD CONSTRAINT fk_bans_account FOREIGN KEY (account_id) REFERENCES users.inactive_accounts ON DELETE CASCADE ON UPDATE CASCADE, ADD CONSTRAINT fk_bans_ban FOREIGN KEY (ban_id) REFERENCES admin.validated_ban_requests; -- -- Table that stores inactivity warning e-mail status -- CREATE TABLE users.inactivity_emails( account_id INT NOT NULL PRIMARY KEY , mail_sent TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT now( ) ); CREATE INDEX idx_inactivitymails_sent ON users.inactivity_emails ( mail_sent ); ALTER TABLE users.inactivity_emails ADD CONSTRAINT fk_inactivitymails_account FOREIGN KEY ( account_id ) REFERENCES users.active_accounts ON DELETE CASCADE ON UPDATE CASCADE;