Database definition & tests organisation
* The main loader script has been updated to generate the list of files it needs to load automatically. As a consequence, files that contained manually-maintained lists of scripts have been removed, and definition directories have been renamed accordingly. * PostgreSQL extension loading and configuration has been moved to a separate script to be loaded automatically in the main transaction. * Data and function definition scripts that had the -data or -functions suffix have been renamed (the suffix is unnecessary). * Unit tests have been reorganised to follow the definition's structure. * Documentation has been improved
This commit is contained in:
parent
b054a379a9
commit
e50775ec76
112 changed files with 78 additions and 144 deletions
legacyworlds-server-data/db-structure/parts/030-data
000-typedefs.sql010-i18n.sql020-prefs.sql030-users.sql035-session.sql040-admin.sql050-accounts.sql055-bugs.sql060-naming.sql070-constants.sql075-resources.sql080-techs.sql090-buildables.sql100-universe.sql110-empires.sql120-construction.sql130-fleets.sql140-status.sql150-logs.sql160-battle.sql170-events.sql180-messages.sql
|
@ -0,0 +1,86 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Type definitions
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
-- Processing status
|
||||
CREATE TYPE processing_status
|
||||
AS ENUM ( 'FUTURE', 'PROCESSING', 'PROCESSED' );
|
||||
|
||||
-- Building output types
|
||||
CREATE TYPE building_output_type
|
||||
AS ENUM ( 'CASH', 'POP', 'DEF', 'WORK' , 'MINE' );
|
||||
|
||||
-- Fleet status
|
||||
CREATE TYPE fleet_status
|
||||
AS ENUM ( 'AVAILABLE', 'DEPLOYING' , 'REDEPLOYING' , 'REDIRECTING' );
|
||||
|
||||
-- Log levels
|
||||
CREATE TYPE log_level
|
||||
AS ENUM ( 'TRACE' , 'DEBUG' , 'INFO' , 'WARNING' , 'ERROR' );
|
||||
|
||||
-- Log types
|
||||
CREATE TYPE log_type
|
||||
AS ENUM ( 'SYS' , 'USERS' , 'ADMIN' );
|
||||
|
||||
-- Update types
|
||||
CREATE TYPE update_type AS ENUM (
|
||||
|
||||
/* Empires' money is being updated using the previous update's results */
|
||||
'EMPIRE_MONEY' ,
|
||||
|
||||
/* Empire research points are being attributed to technologies */
|
||||
'EMPIRE_RESEARCH' ,
|
||||
|
||||
/* The effects of empires' debts are being computed */
|
||||
'EMPIRE_DEBT' ,
|
||||
|
||||
/* Fleets which were 1 update away are arriving at their destination */
|
||||
'PLANET_FLEET_ARRIVALS' ,
|
||||
|
||||
/* Other fleets are moving */
|
||||
'PLANET_FLEET_MOVEMENTS' ,
|
||||
|
||||
/* Fleet states (e.g. "deploying", "unavailable", etc...) are being
|
||||
* updated.
|
||||
*/
|
||||
'PLANET_FLEET_STATUS' ,
|
||||
|
||||
/* Start new battles where necessary */
|
||||
'PLANET_BATTLE_START' ,
|
||||
|
||||
/* Process all in-progress battles */
|
||||
'PLANET_BATTLE_MAIN' ,
|
||||
|
||||
/* Finalise battles that need to be ended */
|
||||
'PLANET_BATTLE_END' ,
|
||||
|
||||
/* Abandon planets */
|
||||
'PLANET_ABANDON' ,
|
||||
|
||||
/* Handle civilian build queues */
|
||||
'PLANET_CONSTRUCTION' ,
|
||||
|
||||
/* Handle military build queues */
|
||||
'PLANET_MILITARY' ,
|
||||
|
||||
/* Update planets' population */
|
||||
'PLANET_POPULATION' ,
|
||||
|
||||
/* Regenerate resources in resource providers */
|
||||
'PLANET_RES_REGEN' ,
|
||||
|
||||
/* Compute income and upkeep of planets */
|
||||
'PLANET_MONEY'
|
||||
);
|
||||
|
||||
-- Types of recapitulative e-mail messages
|
||||
CREATE TYPE recap_type
|
||||
AS ENUM ( 'ADMIN' , 'MSG', 'ERROR' );
|
||||
|
||||
-- Empire relations
|
||||
CREATE TYPE empire_relation_type
|
||||
AS ENUM ('OWN' , 'ALLIED' , 'ENEMY');
|
|
@ -0,0 +1,53 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Translations
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
--
|
||||
-- Languages
|
||||
--
|
||||
CREATE TABLE defs.languages(
|
||||
id SERIAL PRIMARY KEY ,
|
||||
language VARCHAR(5) NOT NULL ,
|
||||
name VARCHAR(48) NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_languages_lid
|
||||
ON defs.languages (language);
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Internationalised strings
|
||||
--
|
||||
CREATE TABLE defs.strings(
|
||||
id SERIAL PRIMARY KEY ,
|
||||
name VARCHAR(64) NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_strings_id
|
||||
ON defs.strings (name);
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Translations
|
||||
--
|
||||
CREATE TABLE defs.translations(
|
||||
lang_id INT NOT NULL ,
|
||||
string_id INT NOT NULL ,
|
||||
translated_string TEXT NOT NULL ,
|
||||
PRIMARY KEY (lang_id, string_id)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_translations_string
|
||||
ON defs.translations (string_id);
|
||||
|
||||
ALTER TABLE defs.translations
|
||||
ADD CONSTRAINT fk_translation_language
|
||||
FOREIGN KEY (lang_id) REFERENCES defs.languages ,
|
||||
ADD CONSTRAINT fk_translation_string
|
||||
FOREIGN KEY (string_id) REFERENCES defs.strings;
|
|
@ -0,0 +1,57 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Preference definitions
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Preference groups
|
||||
--
|
||||
CREATE TABLE defs.preference_groups(
|
||||
id SERIAL PRIMARY KEY ,
|
||||
name VARCHAR(32) NOT NULL ,
|
||||
display_id INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_prefgroups_name
|
||||
ON defs.preference_groups (name);
|
||||
CREATE INDEX idx_prefgroups_dispname
|
||||
ON defs.preference_groups (display_id);
|
||||
|
||||
ALTER TABLE defs.preference_groups
|
||||
ADD CONSTRAINT fk_prefgroups_display
|
||||
FOREIGN KEY (display_id) REFERENCES defs.strings;
|
||||
|
||||
|
||||
--
|
||||
-- Preference definitions
|
||||
--
|
||||
CREATE TABLE defs.preference_definitions(
|
||||
id SERIAL PRIMARY KEY ,
|
||||
group_id INT NOT NULL ,
|
||||
name VARCHAR(32) NOT NULL ,
|
||||
disp_name_id INT NOT NULL ,
|
||||
disp_desc_id INT NOT NULL ,
|
||||
java_type VARCHAR( 255 ) NOT NULL ,
|
||||
default_value TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_prefdefs_group
|
||||
ON defs.preference_definitions (group_id);
|
||||
CREATE UNIQUE INDEX idx_prefdefs_name
|
||||
ON defs.preference_definitions (name);
|
||||
CREATE INDEX idx_prefdefs_dispname
|
||||
ON defs.preference_definitions (disp_name_id);
|
||||
CREATE INDEX idx_prefdefs_dispdesc
|
||||
ON defs.preference_definitions (disp_desc_id);
|
||||
|
||||
ALTER TABLE defs.preference_definitions
|
||||
ADD CONSTRAINT fk_prefdefs_group
|
||||
FOREIGN KEY (group_id) REFERENCES defs.preference_groups ,
|
||||
ADD CONSTRAINT fk_prefdefs_dispname
|
||||
FOREIGN KEY (disp_name_id) REFERENCES defs.strings ,
|
||||
ADD CONSTRAINT fk_prefdefs_dispdesc
|
||||
FOREIGN KEY (disp_desc_id) REFERENCES defs.strings;
|
|
@ -0,0 +1,111 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- User management tables
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
--
|
||||
-- Identifiers sequence for users
|
||||
--
|
||||
CREATE SEQUENCE users.identifiers_seq;
|
||||
|
||||
|
||||
--
|
||||
-- E-mail addresses
|
||||
--
|
||||
CREATE TABLE users.addresses(
|
||||
id INT DEFAULT nextval('users.identifiers_seq') NOT NULL PRIMARY KEY ,
|
||||
address VARCHAR(255) NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_addresses_address
|
||||
ON users.addresses (lower(address));
|
||||
|
||||
|
||||
--
|
||||
-- User credentials
|
||||
--
|
||||
CREATE TABLE users.credentials(
|
||||
address_id INT NOT NULL PRIMARY KEY,
|
||||
pass_md5 CHAR(32) NOT NULL ,
|
||||
pass_sha1 CHAR(40) NOT NULL ,
|
||||
credits INT NOT NULL CHECK (credits >= 0) ,
|
||||
language_id INT NOT NULL
|
||||
);
|
||||
|
||||
ALTER TABLE users.credentials
|
||||
ADD CONSTRAINT fk_credentials_id
|
||||
FOREIGN KEY (address_id) REFERENCES users.addresses
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_credentials_language
|
||||
FOREIGN KEY (language_id) REFERENCES defs.languages;
|
||||
|
||||
|
||||
--
|
||||
-- Validation keys
|
||||
--
|
||||
CREATE TABLE users.validation_keys(
|
||||
credentials_id INT NOT NULL PRIMARY KEY ,
|
||||
token CHAR( 64 ) NOT NULL ,
|
||||
created TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_validationkeys_created
|
||||
ON users.validation_keys (created);
|
||||
|
||||
ALTER TABLE users.validation_keys
|
||||
ADD CONSTRAINT fk_validationkeys_id
|
||||
FOREIGN KEY (credentials_id) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Password recovery
|
||||
--
|
||||
CREATE TABLE users.pwd_recovery_requests(
|
||||
credentials_id INT NOT NULL PRIMARY KEY ,
|
||||
token CHAR( 64 ) NOT NULL ,
|
||||
used BOOLEAN NOT NULL
|
||||
DEFAULT FALSE ,
|
||||
created TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_pwdrecovery_created
|
||||
ON users.pwd_recovery_requests (created);
|
||||
|
||||
ALTER TABLE users.pwd_recovery_requests
|
||||
ADD CONSTRAINT fk_pwdrecovery_id
|
||||
FOREIGN KEY (credentials_id) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Mail address change requests
|
||||
--
|
||||
CREATE TABLE users.address_change_requests(
|
||||
credentials_id INT NOT NULL PRIMARY KEY ,
|
||||
address_id INT NOT NULL ,
|
||||
token CHAR( 64 ) NOT NULL ,
|
||||
used BOOLEAN NOT NULL
|
||||
DEFAULT FALSE ,
|
||||
created TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_addrchangereq_address
|
||||
ON users.address_change_requests (address_id);
|
||||
CREATE INDEX idx_addrchangereq_created
|
||||
ON users.address_change_requests (created);
|
||||
|
||||
ALTER TABLE users.address_change_requests
|
||||
ADD CONSTRAINT fk_addrchangereq_id
|
||||
FOREIGN KEY (credentials_id) REFERENCES users.credentials ON DELETE CASCADE ON UPDATE CASCADE,
|
||||
ADD CONSTRAINT fk_addrchangereq_address
|
||||
FOREIGN KEY (address_id) REFERENCES users.addresses ON DELETE CASCADE;
|
|
@ -0,0 +1,92 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- User sessions tables
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Session client type definitions
|
||||
--
|
||||
|
||||
CREATE TABLE defs.session_clients(
|
||||
id SERIAL PRIMARY KEY ,
|
||||
name VARCHAR( 16 ) NOT NULL UNIQUE ,
|
||||
exclusive BOOLEAN NOT NULL
|
||||
);
|
||||
|
||||
--
|
||||
-- Default session client types
|
||||
--
|
||||
|
||||
INSERT INTO defs.session_clients ( name , exclusive )
|
||||
VALUES( 'web' , TRUE );
|
||||
INSERT INTO defs.session_clients ( name , exclusive )
|
||||
VALUES( 'vac_end' , FALSE );
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Types of session termination
|
||||
--
|
||||
|
||||
CREATE TYPE session_termination_type
|
||||
AS ENUM( 'MANUAL' , 'GONE' , 'EXPIRED' , 'EXCLUSIVE' , 'SERVER' );
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- User sessions start
|
||||
--
|
||||
|
||||
CREATE TABLE users.session_starts(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
credentials_id INT NOT NULL ,
|
||||
client_id INT NOT NULL ,
|
||||
session VARCHAR( 64 ) NOT NULL ,
|
||||
started TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( ) ,
|
||||
from_address VARCHAR( 64 ) NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_sessstart_credentials
|
||||
ON users.session_starts ( credentials_id );
|
||||
|
||||
CREATE INDEX idx_sessstart_client
|
||||
ON users.session_starts ( client_id );
|
||||
|
||||
CREATE INDEX idx_sessstart_started
|
||||
ON users.session_starts ( started );
|
||||
|
||||
ALTER TABLE users.session_starts
|
||||
ADD CONSTRAINT fk_sessstart_credentials
|
||||
FOREIGN KEY ( credentials_id ) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE ,
|
||||
ADD CONSTRAINT fk_sessstart_client
|
||||
FOREIGN KEY ( client_id ) REFERENCES defs.session_clients;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- User sessions end
|
||||
--
|
||||
|
||||
CREATE TABLE users.session_ends(
|
||||
id BIGINT NOT NULL PRIMARY KEY ,
|
||||
ended TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( ) ,
|
||||
end_type session_termination_type NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_sessend_ended
|
||||
ON users.session_ends ( ended );
|
||||
|
||||
ALTER TABLE users.session_ends
|
||||
ADD CONSTRAINT fk_sessend_id
|
||||
FOREIGN KEY ( id ) REFERENCES users.session_starts
|
||||
ON DELETE CASCADE;
|
||||
|
|
@ -0,0 +1,169 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Administrative tables
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
--
|
||||
-- Administrators
|
||||
--
|
||||
CREATE TABLE admin.administrators(
|
||||
id SERIAL NOT NULL PRIMARY KEY ,
|
||||
appear_as VARCHAR( 48 ) NOT NULL ,
|
||||
pass_md5 CHAR(32) NOT NULL ,
|
||||
pass_sha1 CHAR(40) NOT NULL ,
|
||||
privileges INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_administrators_appearas
|
||||
ON admin.administrators( lower(appear_as) );
|
||||
|
||||
|
||||
--
|
||||
-- Administrators <-> credentials
|
||||
--
|
||||
CREATE TABLE admin.admin_credentials(
|
||||
administrator_id INT NOT NULL ,
|
||||
credentials_id INT NOT NULL ,
|
||||
PRIMARY KEY(administrator_id)
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_admincreds_creds
|
||||
ON admin.admin_credentials( credentials_id );
|
||||
|
||||
ALTER TABLE admin.admin_credentials
|
||||
ADD CONSTRAINT fk_admincreds_admin
|
||||
FOREIGN KEY (administrator_id) REFERENCES admin.administrators ,
|
||||
ADD CONSTRAINT fk_admincreds_creds
|
||||
FOREIGN KEY (credentials_id) REFERENCES users.credentials
|
||||
ON UPDATE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Ban requests
|
||||
--
|
||||
CREATE TABLE admin.ban_requests(
|
||||
id SERIAL NOT NULL PRIMARY KEY ,
|
||||
requested_by INT NOT NULL ,
|
||||
reason TEXT NOT NULL ,
|
||||
requested TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_banrequests_requestedby
|
||||
ON admin.ban_requests( requested_by );
|
||||
|
||||
ALTER TABLE admin.ban_requests
|
||||
ADD CONSTRAINT fk_banrequests_requestedby
|
||||
FOREIGN KEY (requested_by) REFERENCES admin.administrators;
|
||||
|
||||
|
||||
--
|
||||
-- Active ban requests
|
||||
--
|
||||
CREATE TABLE admin.active_ban_requests(
|
||||
request_id INT NOT NULL PRIMARY KEY ,
|
||||
credentials_id INT NOT NULL ,
|
||||
validated BOOLEAN NOT NULL
|
||||
DEFAULT FALSE
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_activebanrequests_creds
|
||||
ON admin.active_ban_requests (credentials_id);
|
||||
|
||||
ALTER TABLE admin.active_ban_requests
|
||||
ADD CONSTRAINT fk_activebanrequests_request
|
||||
FOREIGN KEY (request_id) REFERENCES admin.ban_requests ,
|
||||
ADD CONSTRAINT fk_activebanrequests_creds
|
||||
FOREIGN KEY (credentials_id) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Archived ban requests
|
||||
--
|
||||
CREATE TABLE admin.archived_ban_requests(
|
||||
request_id INT NOT NULL PRIMARY KEY ,
|
||||
credentials_id INT NOT NULL ,
|
||||
updated TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_archivedbanrequests_creds
|
||||
ON admin.archived_ban_requests (credentials_id);
|
||||
|
||||
ALTER TABLE admin.archived_ban_requests
|
||||
ADD CONSTRAINT fk_archivedbanrequests_request
|
||||
FOREIGN KEY (request_id) REFERENCES admin.ban_requests ,
|
||||
ADD CONSTRAINT fk_archivedbanrequests_creds
|
||||
FOREIGN KEY (credentials_id) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Rejected ban requests
|
||||
--
|
||||
CREATE TABLE admin.rejected_ban_requests(
|
||||
request_id INT NOT NULL PRIMARY KEY ,
|
||||
rejected_by INT NOT NULL ,
|
||||
reason TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_rejectedbanrequests_rejected
|
||||
ON admin.rejected_ban_requests (rejected_by);
|
||||
|
||||
ALTER TABLE admin.rejected_ban_requests
|
||||
ADD CONSTRAINT fk_rejectedbanrequests_request
|
||||
FOREIGN KEY (request_id) REFERENCES admin.ban_requests ,
|
||||
ADD CONSTRAINT fk_rejectedbanrequests_rejected
|
||||
FOREIGN KEY (rejected_by) REFERENCES admin.administrators;
|
||||
|
||||
|
||||
--
|
||||
-- Validated ban requests
|
||||
--
|
||||
CREATE TABLE admin.validated_ban_requests(
|
||||
request_id INT NOT NULL PRIMARY KEY ,
|
||||
validated_by INT NOT NULL ,
|
||||
validated TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_validatedbanrequests_validated
|
||||
ON admin.validated_ban_requests (validated_by);
|
||||
|
||||
ALTER TABLE admin.validated_ban_requests
|
||||
ADD CONSTRAINT fk_validatedbanrequests_request
|
||||
FOREIGN KEY (request_id) REFERENCES admin.ban_requests ,
|
||||
ADD CONSTRAINT fk_validatedbanrequests_rejected
|
||||
FOREIGN KEY (validated_by) REFERENCES admin.administrators;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Warnings to users
|
||||
--
|
||||
|
||||
CREATE TABLE admin.warnings (
|
||||
credentials_id INT NOT NULL PRIMARY KEY ,
|
||||
warnings INT NOT NULL
|
||||
DEFAULT 1
|
||||
CHECK( warnings >= 0 ) ,
|
||||
last_received TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_warnings_received
|
||||
ON admin.warnings( last_received )
|
||||
WHERE warnings > 0;
|
||||
|
||||
ALTER TABLE admin.warnings
|
||||
ADD CONSTRAINT fk_warnings_credentials
|
||||
FOREIGN KEY ( credentials_id ) REFERENCES users.credentials
|
||||
ON UPDATE CASCADE ON DELETE CASCADE;
|
|
@ -0,0 +1,137 @@
|
|||
-- 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;
|
||||
|
|
@ -0,0 +1,273 @@
|
|||
-- 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;
|
|
@ -0,0 +1,109 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Empire/map object names
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Banned names
|
||||
--
|
||||
|
||||
CREATE TABLE naming.banned_names(
|
||||
name VARCHAR(20) NOT NULL ,
|
||||
added_by INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_bannednames_name
|
||||
ON naming.banned_names( lower(name) );
|
||||
CREATE INDEX idx_bannednames_addedby
|
||||
ON naming.banned_names (added_by);
|
||||
|
||||
ALTER TABLE naming.banned_names
|
||||
ADD CONSTRAINT fk_bannednames_addedby
|
||||
FOREIGN KEY (added_by) REFERENCES admin.administrators;
|
||||
|
||||
|
||||
--
|
||||
-- Empire names
|
||||
--
|
||||
|
||||
CREATE TABLE naming.empire_names (
|
||||
id SERIAL NOT NULL PRIMARY KEY ,
|
||||
owner_id INT NOT NULL ,
|
||||
name VARCHAR(20) NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_empirenames_name
|
||||
ON naming.empire_names( lower(name) );
|
||||
CREATE INDEX idx_empirenames_owner
|
||||
ON naming.empire_names( owner_id );
|
||||
|
||||
ALTER TABLE naming.empire_names
|
||||
ADD CONSTRAINT fk_empirenames_owner
|
||||
FOREIGN KEY (owner_id) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
GRANT SELECT ON naming.empire_names TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Map names
|
||||
--
|
||||
CREATE TABLE naming.map_names(
|
||||
id SERIAL NOT NULL PRIMARY KEY ,
|
||||
name VARCHAR(20) NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_mapnames_name
|
||||
ON naming.map_names( lower(name) );
|
||||
|
||||
|
||||
--
|
||||
-- Changed map names
|
||||
--
|
||||
|
||||
CREATE TABLE naming.changed_map_names(
|
||||
name_id INT NOT NULL PRIMARY KEY ,
|
||||
named_by INT NOT NULL ,
|
||||
named_at TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_changedmapnames_namedby
|
||||
ON naming.changed_map_names (named_by);
|
||||
|
||||
ALTER TABLE naming.changed_map_names
|
||||
ADD CONSTRAINT fk_changedmapnames_name
|
||||
FOREIGN KEY (name_id) REFERENCES naming.map_names ,
|
||||
ADD CONSTRAINT fk_changedmapnames_namedby
|
||||
FOREIGN KEY (named_by) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Validated map names
|
||||
--
|
||||
|
||||
CREATE TABLE naming.validated_map_names(
|
||||
name_id INT NOT NULL PRIMARY KEY ,
|
||||
validated_by INT NOT NULL ,
|
||||
validated_at TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_validatedmapnames_namedby
|
||||
ON naming.validated_map_names (validated_by);
|
||||
|
||||
|
||||
ALTER TABLE naming.validated_map_names
|
||||
ADD CONSTRAINT fk_validatedmapnames_name
|
||||
FOREIGN KEY (name_id) REFERENCES naming.changed_map_names
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_validatedmapnames_validatedby
|
||||
FOREIGN KEY (validated_by) REFERENCES admin.administrators;
|
|
@ -0,0 +1,44 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- System "constants"
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
--
|
||||
-- Constant categories
|
||||
--
|
||||
CREATE TABLE sys.constant_categories(
|
||||
id SERIAL NOT NULL PRIMARY KEY ,
|
||||
name VARCHAR(64) NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_constantcategories_name
|
||||
ON sys.constant_categories (name);
|
||||
|
||||
|
||||
--
|
||||
-- Constant definitions and values
|
||||
--
|
||||
CREATE TABLE sys.constant_definitions(
|
||||
name VARCHAR(64) NOT NULL PRIMARY KEY,
|
||||
category_id INT NOT NULL ,
|
||||
description TEXT NOT NULL ,
|
||||
min_value REAL ,
|
||||
max_value REAL ,
|
||||
c_value REAL NOT NULL ,
|
||||
CHECK(
|
||||
( min_value IS NULL OR (
|
||||
min_value IS NOT NULL AND c_value >= min_value ) )
|
||||
AND ( max_value IS NULL OR (
|
||||
max_value IS NOT NULL AND max_value >= c_value ) )
|
||||
)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_constantdefinitions_category
|
||||
ON sys.constant_definitions (category_id);
|
||||
|
||||
ALTER TABLE sys.constant_definitions
|
||||
ADD CONSTRAINT fk_constraintdefinitions_category
|
||||
FOREIGN KEY (category_id) REFERENCES sys.constant_categories;
|
|
@ -0,0 +1,121 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Resource definitions
|
||||
--
|
||||
-- Copyright(C) 2004-2011, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
/*
|
||||
* Common resource definitions
|
||||
* ----------------------------
|
||||
*
|
||||
* The defs.resources table is used to describe the part of a resource's
|
||||
* definition that's idependant
|
||||
*/
|
||||
|
||||
CREATE TABLE defs.resources(
|
||||
/* The resource identifier is a reference to an I18N string that
|
||||
* represents the resource's name. It also serves as the table's
|
||||
* primary key.
|
||||
*/
|
||||
resource_name_id INT NOT NULL PRIMARY KEY ,
|
||||
|
||||
/* Identifier of an I18N string which serves as the resource's
|
||||
* description.
|
||||
*/
|
||||
resource_description_id INT NOT NULL ,
|
||||
|
||||
/* Identifier of an I18N string that names the resource's category. This
|
||||
* field may be NULL for resources that do not belong to a category.
|
||||
*/
|
||||
resource_category_id INT ,
|
||||
|
||||
/* The weight is used when sorting resources. For resources that do not
|
||||
* have a category, it is used directly. Otherwise, categories themselves
|
||||
* are sorted by average weight of their contents, and resources in
|
||||
* categories are sorted by weight.
|
||||
*/
|
||||
resource_weight INT NOT NULL
|
||||
CHECK ( resource_weight > 0 )
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_resources_description
|
||||
ON defs.resources( resource_description_id );
|
||||
CREATE INDEX idx_resources_category
|
||||
ON defs.resources( resource_category_id );
|
||||
CREATE INDEX idx_resources_weight
|
||||
ON defs.resources( resource_weight );
|
||||
|
||||
ALTER TABLE defs.resources
|
||||
ADD CONSTRAINT fk_resources_name
|
||||
FOREIGN KEY ( resource_name_id ) REFERENCES defs.strings ,
|
||||
ADD CONSTRAINT fk_resources_description
|
||||
FOREIGN KEY ( resource_description_id ) REFERENCES defs.strings ,
|
||||
ADD CONSTRAINT fk_resources_category
|
||||
FOREIGN KEY ( resource_category_id ) REFERENCES defs.strings;
|
||||
|
||||
|
||||
|
||||
/*
|
||||
* Natural resources
|
||||
* ------------------
|
||||
*
|
||||
* This table contains additional resource information that is used for
|
||||
* natural resources only. These fields are used by the universe generator
|
||||
* when it creates resource providers.
|
||||
*/
|
||||
CREATE TABLE defs.natural_resources (
|
||||
/* Identifier of the resource definition for this natural resource, which
|
||||
* also serves as the primary key for this table.
|
||||
*/
|
||||
resource_name_id INT NOT NULL PRIMARY KEY ,
|
||||
|
||||
/* Presence probability, used by the universe generator to determine
|
||||
* whether some type of resource should be added to a planet or not. The
|
||||
* generator will try to enforce this probability on the universe in
|
||||
* general (that is, not assigning the resource to a planet will increase
|
||||
* the probability of it being assigned to another).
|
||||
*/
|
||||
natres_p_presence DOUBLE PRECISION NOT NULL
|
||||
CHECK ( natres_p_presence > 0
|
||||
AND natres_p_presence < 1 ) ,
|
||||
|
||||
/* Average quantity in resource providers. */
|
||||
natres_quantity_avg DOUBLE PRECISION NOT NULL
|
||||
CHECK( natres_quantity_avg > 0 ) ,
|
||||
/* Maximal deviation from the average quantity. */
|
||||
natres_quantity_dev DOUBLE PRECISION NOT NULL
|
||||
CHECK( natres_quantity_dev >= 0 ) ,
|
||||
|
||||
/* Average extraction difficulty assigned to resource providers */
|
||||
natres_difficulty_avg DOUBLE PRECISION NOT NULL
|
||||
CHECK( natres_difficulty_avg BETWEEN 0 AND 1 ) ,
|
||||
/* Maximal deviation from the average extraction difficulty */
|
||||
natres_difficulty_dev DOUBLE PRECISION NOT NULL
|
||||
CHECK( natres_difficulty_dev >= 0 ) ,
|
||||
|
||||
/* Average recovery rate for resource providers */
|
||||
natres_recovery_avg DOUBLE PRECISION NOT NULL
|
||||
CHECK( natres_recovery_avg > 0
|
||||
AND natres_recovery_avg <= 1 ) ,
|
||||
/* Maximal deviation from the average recovery rate */
|
||||
natres_recovery_dev DOUBLE PRECISION NOT NULL
|
||||
CHECK( natres_recovery_dev >= 0 ) ,
|
||||
|
||||
/*
|
||||
* For all values which include both an average and a maximal deviation,
|
||||
* make sure the range defined by the deviation is still within valid
|
||||
* boundaries for the value in question.
|
||||
*/
|
||||
CHECK( natres_quantity_avg - natres_quantity_dev > 0 ) ,
|
||||
CHECK( natres_difficulty_avg + natres_difficulty_dev <= 1 ) ,
|
||||
CHECK( natres_difficulty_avg - natres_difficulty_dev >= 0 ) ,
|
||||
CHECK( natres_recovery_avg + natres_recovery_dev <= 1 ) ,
|
||||
CHECK( natres_recovery_avg - natres_recovery_dev > 0 )
|
||||
);
|
||||
|
||||
ALTER TABLE defs.natural_resources
|
||||
ADD CONSTRAINT fk_natres_resource
|
||||
FOREIGN KEY ( resource_name_id ) REFERENCES defs.resources;
|
|
@ -0,0 +1,56 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Technology definitions
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Technology lines
|
||||
--
|
||||
|
||||
CREATE TABLE tech.lines(
|
||||
name_id INT NOT NULL PRIMARY KEY ,
|
||||
description_id INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_lines_description
|
||||
ON tech.lines (description_id);
|
||||
|
||||
ALTER TABLE tech.lines
|
||||
ADD CONSTRAINT fk_lines_name
|
||||
FOREIGN KEY (name_id) REFERENCES defs.strings ,
|
||||
ADD CONSTRAINT fk_lines_description
|
||||
FOREIGN KEY (description_id) REFERENCES defs.strings;
|
||||
|
||||
|
||||
--
|
||||
-- Technology levels
|
||||
--
|
||||
|
||||
CREATE TABLE tech.levels(
|
||||
id SERIAL NOT NULL PRIMARY KEY ,
|
||||
line_id INT NOT NULL ,
|
||||
level INT NOT NULL CHECK( level > 0 ) ,
|
||||
name_id INT NOT NULL ,
|
||||
description_id INT NOT NULL ,
|
||||
points INT NOT NULL CHECK( points > 0 ) ,
|
||||
cost INT NOT NULL CHECK( cost > 0 )
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_levels_linelevel
|
||||
ON tech.levels (line_id, level);
|
||||
CREATE INDEX idx_levels_name
|
||||
ON tech.levels (name_id);
|
||||
CREATE INDEX idx_levels_description
|
||||
ON tech.levels (description_id);
|
||||
|
||||
ALTER TABLE tech.levels
|
||||
ADD CONSTRAINT fk_levels_line
|
||||
FOREIGN KEY (line_id) REFERENCES tech.lines ,
|
||||
ADD CONSTRAINT fk_levels_name
|
||||
FOREIGN KEY (name_id) REFERENCES defs.strings ,
|
||||
ADD CONSTRAINT fk_levels_description
|
||||
FOREIGN KEY (description_id) REFERENCES defs.strings;
|
|
@ -0,0 +1,75 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Buildings/ships definitions
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
--
|
||||
-- "Buildables"
|
||||
--
|
||||
CREATE TABLE tech.buildables(
|
||||
name_id INT NOT NULL PRIMARY KEY ,
|
||||
description_id INT NOT NULL ,
|
||||
cost INT NOT NULL CHECK( cost > 0 ) ,
|
||||
work INT NOT NULL CHECK( work > 0 ) ,
|
||||
upkeep INT NOT NULL CHECK( upkeep >= 0 )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_buildables_description
|
||||
ON tech.buildables (description_id);
|
||||
|
||||
ALTER TABLE tech.buildables
|
||||
ADD CONSTRAINT fk_buildables_name
|
||||
FOREIGN KEY (name_id) REFERENCES defs.strings ,
|
||||
ADD CONSTRAINT fk_buildables_description
|
||||
FOREIGN KEY (description_id) REFERENCES defs.strings;
|
||||
|
||||
|
||||
--
|
||||
-- Requirements
|
||||
--
|
||||
CREATE TABLE tech.buildable_requirements(
|
||||
buildable_id INT NOT NULL ,
|
||||
level_id INT NOT NULL ,
|
||||
PRIMARY KEY( buildable_id , level_id )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_buildablereqs_level
|
||||
ON tech.buildable_requirements( level_id );
|
||||
|
||||
ALTER TABLE tech.buildable_requirements
|
||||
ADD CONSTRAINT fk_buildablereqs_buildable
|
||||
FOREIGN KEY (buildable_id) REFERENCES tech.buildables ,
|
||||
ADD CONSTRAINT fk_buildablereqs_level
|
||||
FOREIGN KEY (level_id) REFERENCES tech.levels;
|
||||
|
||||
|
||||
--
|
||||
-- Buildings
|
||||
--
|
||||
CREATE TABLE tech.buildings(
|
||||
buildable_id INT NOT NULL PRIMARY KEY ,
|
||||
workers INT NOT NULL CHECK( workers >= 0 ) ,
|
||||
output_type building_output_type ,
|
||||
output INT NOT NULL CHECK( output > 0 )
|
||||
);
|
||||
|
||||
ALTER TABLE tech.buildings
|
||||
ADD CONSTRAINT fk_buildings_buildable
|
||||
FOREIGN KEY (buildable_id) REFERENCES tech.buildables;
|
||||
|
||||
--
|
||||
-- Ships
|
||||
--
|
||||
CREATE TABLE tech.ships(
|
||||
buildable_id INT NOT NULL PRIMARY KEY ,
|
||||
flight_time INT NOT NULL CHECK( flight_time > 0 ) ,
|
||||
power INT NOT NULL CHECK( power > 0 )
|
||||
);
|
||||
|
||||
|
||||
ALTER TABLE tech.ships
|
||||
ADD CONSTRAINT fk_buildings_buildable
|
||||
FOREIGN KEY (buildable_id) REFERENCES tech.buildables;
|
|
@ -0,0 +1,156 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Stellar systems and planets
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Stellar systems
|
||||
--
|
||||
CREATE TABLE verse.systems(
|
||||
id SERIAL NOT NULL PRIMARY KEY ,
|
||||
x INT NOT NULL ,
|
||||
y INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_systems_coordinates
|
||||
ON verse.systems( x , y );
|
||||
|
||||
--
|
||||
-- Planets
|
||||
--
|
||||
CREATE TABLE verse.planets(
|
||||
name_id INT NOT NULL PRIMARY KEY ,
|
||||
system_id INT NOT NULL ,
|
||||
orbit INT NOT NULL
|
||||
CHECK( orbit BETWEEN 1 AND 5 ) ,
|
||||
picture INT NOT NULL ,
|
||||
population REAL NOT NULL
|
||||
CHECK( population >= 0 )
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_planets_coordinates
|
||||
ON verse.planets( system_id , orbit );
|
||||
|
||||
ALTER TABLE verse.planets
|
||||
ADD CONSTRAINT fk_planets_name
|
||||
FOREIGN KEY (name_id) REFERENCES naming.map_names ,
|
||||
ADD CONSTRAINT fk_planets_system
|
||||
FOREIGN KEY (system_id) REFERENCES verse.systems;
|
||||
|
||||
|
||||
|
||||
/*
|
||||
* Resource providers
|
||||
* -------------------
|
||||
*
|
||||
* A resource provider allows natural resources to be extracted. Resource
|
||||
* providers are initialised by the universe generator and updated when
|
||||
* mining results are computed.
|
||||
*
|
||||
* For now, resource providers are bound to planets. Each planet may only
|
||||
* have one provider for a given type of natural resource.
|
||||
*/
|
||||
CREATE TABLE verse.resource_providers(
|
||||
|
||||
/* The identifier of the planet the resource provider is bound to. */
|
||||
planet_id INT NOT NULL ,
|
||||
|
||||
/* The identifier of the natural resource that can be mined from this
|
||||
* resource provider.
|
||||
*/
|
||||
resource_name_id INT NOT NULL ,
|
||||
|
||||
/* The maximal quantity of resource units in the provider */
|
||||
resprov_quantity_max DOUBLE PRECISION NOT NULL
|
||||
CHECK( resprov_quantity_max > 0 ) ,
|
||||
/* The current quantity of resources */
|
||||
resprov_quantity DOUBLE PRECISION NOT NULL
|
||||
CHECK( resprov_quantity >= 0 ) ,
|
||||
|
||||
/* The extraction difficulty, which affects the amount of work required to
|
||||
* extract resources.
|
||||
*/
|
||||
resprov_difficulty DOUBLE PRECISION NOT NULL
|
||||
CHECK( resprov_difficulty BETWEEN 0 AND 1 ) ,
|
||||
|
||||
/* The provider's recovery rate, which determines how fast the provider's
|
||||
* resources are regenerated.
|
||||
*/
|
||||
resprov_recovery DOUBLE PRECISION NOT NULL
|
||||
CHECK( resprov_recovery > 0
|
||||
AND resprov_recovery <= 1 ) ,
|
||||
|
||||
/* Primary key on (planet,type of resource) */
|
||||
PRIMARY KEY( planet_id , resource_name_id ) ,
|
||||
|
||||
/* Make sure the quantity is always equal or smaller than the maximal
|
||||
* quantity.
|
||||
*/
|
||||
CHECK( resprov_quantity <= resprov_quantity_max )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_resprov_resource
|
||||
ON verse.resource_providers( resource_name_id );
|
||||
|
||||
ALTER TABLE verse.resource_providers
|
||||
ADD CONSTRAINT fk_resprov_planet
|
||||
FOREIGN KEY ( planet_id ) REFERENCES verse.planets ,
|
||||
ADD CONSTRAINT fk_resprov_resource
|
||||
FOREIGN KEY ( resource_name_id ) REFERENCES defs.natural_resources;
|
||||
|
||||
|
||||
--
|
||||
-- Happiness
|
||||
--
|
||||
CREATE TABLE verse.planet_happiness(
|
||||
planet_id INT NOT NULL PRIMARY KEY ,
|
||||
target REAL NOT NULL
|
||||
CHECK( target BETWEEN 0.0 AND 1.0 ) ,
|
||||
current REAL NOT NULL
|
||||
CHECK( current > 0 )
|
||||
);
|
||||
|
||||
ALTER TABLE verse.planet_happiness
|
||||
ADD CONSTRAINT fk_planethappiness_planet
|
||||
FOREIGN KEY (planet_id) REFERENCES verse.planets;
|
||||
|
||||
|
||||
--
|
||||
-- Money
|
||||
--
|
||||
CREATE TABLE verse.planet_money(
|
||||
planet_id INT NOT NULL PRIMARY KEY ,
|
||||
income REAL NOT NULL
|
||||
CHECK( income >= 0 ) ,
|
||||
upkeep REAL NOT NULL
|
||||
CHECK( upkeep >= 0 )
|
||||
);
|
||||
|
||||
ALTER TABLE verse.planet_money
|
||||
ADD CONSTRAINT fk_planetmoney_planet
|
||||
FOREIGN KEY (planet_id) REFERENCES verse.planets;
|
||||
|
||||
|
||||
--
|
||||
-- Buildings
|
||||
--
|
||||
CREATE TABLE verse.planet_buildings(
|
||||
planet_id INT NOT NULL ,
|
||||
building_id INT NOT NULL ,
|
||||
amount INT NOT NULL CHECK( amount >= 0 ) ,
|
||||
damage REAL NOT NULL CHECK( damage >= 0 ) ,
|
||||
PRIMARY KEY( planet_id , building_id )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_planetbuildings_building
|
||||
ON verse.planet_buildings (building_id);
|
||||
|
||||
ALTER TABLE verse.planet_buildings
|
||||
ADD CONSTRAINT fk_planetbuildings_planet
|
||||
FOREIGN KEY (planet_id) REFERENCES verse.planets ,
|
||||
ADD CONSTRAINT fk_planetbuildings_building
|
||||
FOREIGN KEY (building_id) REFERENCES tech.buildings;
|
|
@ -0,0 +1,304 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Empires and alliances
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Empires
|
||||
--
|
||||
|
||||
CREATE TABLE emp.empires(
|
||||
name_id INT NOT NULL PRIMARY KEY ,
|
||||
cash REAL NOT NULL
|
||||
CHECK( cash >= 0 ),
|
||||
debt REAL NOT NULL DEFAULT 0
|
||||
CHECK( debt >= 0)
|
||||
);
|
||||
|
||||
ALTER TABLE emp.empires
|
||||
ADD CONSTRAINT fk_empires_name
|
||||
FOREIGN KEY (name_id) REFERENCES naming.empire_names;
|
||||
|
||||
|
||||
/*
|
||||
* Empire resources
|
||||
* -----------------
|
||||
*
|
||||
* This table contains the list of resources possessed and owed by each
|
||||
* empire.
|
||||
*/
|
||||
|
||||
CREATE TABLE emp.resources(
|
||||
/* Identifier of the empire */
|
||||
empire_id INT NOT NULL ,
|
||||
|
||||
/* Identifier of the type of resource */
|
||||
resource_name_id INT NOT NULL ,
|
||||
|
||||
/* Amount of that specific resource possessed by the empire */
|
||||
empres_possessed DOUBLE PRECISION NOT NULL
|
||||
DEFAULT 0
|
||||
CHECK( empres_possessed >= 0 ) ,
|
||||
|
||||
/* Amount of that specific resource owed by the empire. This value is
|
||||
* used to accumulate debts and that, in turn, is used when computing
|
||||
* debt-related fleet and building destruction.
|
||||
*/
|
||||
empres_owed DOUBLE PRECISION NOT NULL
|
||||
DEFAULT 0
|
||||
CHECK( empres_owed >= 0 ) ,
|
||||
|
||||
/* There is only one entry for each (empire,type of resource) pair */
|
||||
PRIMARY KEY( empire_id , resource_name_id )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_empres_resource
|
||||
ON emp.resources ( resource_name_id );
|
||||
|
||||
ALTER TABLE emp.resources
|
||||
ADD CONSTRAINT fk_empres_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_empres_resource
|
||||
FOREIGN KEY ( resource_name_id ) REFERENCES defs.resources;
|
||||
|
||||
|
||||
--
|
||||
-- Empire technologies
|
||||
--
|
||||
|
||||
CREATE TABLE emp.technologies(
|
||||
empire_id INT NOT NULL ,
|
||||
line_id INT NOT NULL ,
|
||||
level INT NOT NULL DEFAULT 1
|
||||
CHECK( level > 0 ) ,
|
||||
accumulated REAL NOT NULL DEFAULT 0
|
||||
CHECK( accumulated >= 0 ),
|
||||
PRIMARY KEY( empire_id , line_id )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_technologies_line
|
||||
ON emp.technologies (line_id);
|
||||
|
||||
ALTER TABLE emp.technologies
|
||||
ADD CONSTRAINT fk_technologies_empire
|
||||
FOREIGN KEY (empire_id) REFERENCES emp.empires
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_technologies_line
|
||||
FOREIGN KEY (line_id) REFERENCES tech.lines;
|
||||
|
||||
|
||||
--
|
||||
-- Empire planets
|
||||
--
|
||||
|
||||
CREATE TABLE emp.planets(
|
||||
planet_id INT NOT NULL PRIMARY KEY ,
|
||||
empire_id INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_planets_empire
|
||||
ON emp.planets (empire_id);
|
||||
|
||||
ALTER TABLE emp.planets
|
||||
ADD CONSTRAINT fk_eplanets_planet
|
||||
FOREIGN KEY (planet_id) REFERENCES verse.planets ,
|
||||
ADD CONSTRAINT fk_eplanets_empire
|
||||
FOREIGN KEY (empire_id) REFERENCES emp.empires
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
/*
|
||||
* Empire mining settings
|
||||
* -----------------------
|
||||
*
|
||||
* This table is used to store general empire mining settings. When the empire
|
||||
* gains control over a new planet, or if the planet does not have specific
|
||||
* settings, these settings are used to determine the amount of work units
|
||||
* that go into extracting each type of resource.
|
||||
*
|
||||
* Empire-wide settings are ignored if the planet has specific settings, or if
|
||||
* none of the resources present on the planet have a positive weight (in
|
||||
* which case all present resources are extracted as if they had the same
|
||||
* weight).
|
||||
*/
|
||||
|
||||
CREATE TABLE emp.mining_settings(
|
||||
/* Identifier of the empire */
|
||||
empire_id INT NOT NULL ,
|
||||
|
||||
/* Identifier of the type of resources */
|
||||
resource_name_id INT NOT NULL ,
|
||||
|
||||
/* Weight to give to this type of resource when there are no planet-
|
||||
* specific settings.
|
||||
*/
|
||||
empmset_weight INT NOT NULL
|
||||
DEFAULT 1
|
||||
CHECK( empmset_weight >= 0 ) ,
|
||||
|
||||
/* Primary key on (empire,resource type) pairs */
|
||||
PRIMARY KEY( empire_id , resource_name_id )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_empmset_resource
|
||||
ON emp.mining_settings ( resource_name_id );
|
||||
|
||||
ALTER TABLE emp.mining_settings
|
||||
ADD CONSTRAINT fk_empmset_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_empmset_resource
|
||||
FOREIGN KEY ( resource_name_id ) REFERENCES defs.natural_resources;
|
||||
|
||||
|
||||
/*
|
||||
* Planet-specific mining settings
|
||||
* --------------------------------
|
||||
*
|
||||
* Empire may set planet-specific mining settings when they own a planet. Even
|
||||
* once the empire abandons the planet (or when it is taken away), the
|
||||
* settings are kept in the database and restored if the empire takes control
|
||||
* over the planet again.
|
||||
*/
|
||||
|
||||
CREATE TABLE emp.planet_mining_settings(
|
||||
/* Identifier of the empire */
|
||||
empire_id INT NOT NULL ,
|
||||
|
||||
/* The identifier of the planet */
|
||||
planet_id INT NOT NULL ,
|
||||
|
||||
/* Identifier of the type of resources */
|
||||
resource_name_id INT NOT NULL ,
|
||||
|
||||
/* Weight to give to this type of resource */
|
||||
emppmset_weight INT NOT NULL
|
||||
DEFAULT 1
|
||||
CHECK( emppmset_weight >= 0 ) ,
|
||||
|
||||
/* Primary key on (empire,resource type) pairs */
|
||||
PRIMARY KEY( empire_id , planet_id , resource_name_id )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_emppmset_provider
|
||||
ON emp.planet_mining_settings ( planet_id , resource_name_id );
|
||||
|
||||
ALTER TABLE emp.planet_mining_settings
|
||||
ADD CONSTRAINT fk_emppmset_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_emppmset_resource
|
||||
FOREIGN KEY ( planet_id , resource_name_id )
|
||||
REFERENCES verse.resource_providers;
|
||||
|
||||
|
||||
--
|
||||
-- Planets being abandonned
|
||||
--
|
||||
|
||||
CREATE TABLE emp.abandon(
|
||||
planet_id INT NOT NULL PRIMARY KEY ,
|
||||
time_left INT NOT NULL CHECK ( time_left > 0 )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_abandon_ready
|
||||
ON emp.abandon ( ( time_left = 1 ) );
|
||||
|
||||
ALTER TABLE emp.abandon
|
||||
ADD CONSTRAINT fk_abandon_planet
|
||||
FOREIGN KEY (planet_id) REFERENCES emp.planets
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Alliances
|
||||
--
|
||||
|
||||
CREATE TABLE emp.alliances(
|
||||
id SERIAL NOT NULL PRIMARY KEY ,
|
||||
tag VARCHAR(5) NOT NULL ,
|
||||
name VARCHAR(128) NOT NULL ,
|
||||
leader_id INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_alliances_tag
|
||||
ON emp.alliances ( lower(tag) );
|
||||
CREATE UNIQUE INDEX idx_alliances_leader
|
||||
ON emp.alliances (leader_id);
|
||||
|
||||
ALTER TABLE emp.alliances
|
||||
ADD CONSTRAINT fk_alliances_leader
|
||||
FOREIGN KEY (leader_id) REFERENCES emp.empires
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Alliance membership
|
||||
--
|
||||
|
||||
CREATE TABLE emp.alliance_members(
|
||||
empire_id INT NOT NULL PRIMARY KEY ,
|
||||
alliance_id INT NOT NULL ,
|
||||
is_pending BOOLEAN NOT NULL
|
||||
DEFAULT TRUE
|
||||
);
|
||||
|
||||
CREATE INDEX idx_alliancemembers_alliance
|
||||
ON emp.alliance_members( alliance_id );
|
||||
|
||||
ALTER TABLE emp.alliance_members
|
||||
ADD CONSTRAINT fk_alliancemembers_empire
|
||||
FOREIGN KEY (empire_id) REFERENCES emp.empires
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_alliancemembers_alliance
|
||||
FOREIGN KEY (alliance_id) REFERENCES emp.alliances
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Enemy lists, alliances
|
||||
--
|
||||
|
||||
CREATE TABLE emp.enemy_alliances(
|
||||
empire_id INT NOT NULL ,
|
||||
alliance_id INT NOT NULL ,
|
||||
PRIMARY KEY (empire_id,alliance_id)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_enemyalliances_alliance
|
||||
ON emp.enemy_alliances (alliance_id);
|
||||
|
||||
ALTER TABLE emp.enemy_alliances
|
||||
ADD CONSTRAINT fk_enemyalliances_empire
|
||||
FOREIGN KEY (empire_id) REFERENCES emp.empires
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_enemyalliances_alliance
|
||||
FOREIGN KEY (alliance_id) REFERENCES emp.alliances
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Enemy lists, empires
|
||||
--
|
||||
|
||||
CREATE TABLE emp.enemy_empires(
|
||||
empire_id INT NOT NULL ,
|
||||
enemy_id INT NOT NULL ,
|
||||
PRIMARY KEY (empire_id,enemy_id)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_enemyempires_enemy
|
||||
ON emp.enemy_empires (enemy_id);
|
||||
|
||||
ALTER TABLE emp.enemy_empires
|
||||
ADD CONSTRAINT fk_enemyempires_empire
|
||||
FOREIGN KEY (empire_id) REFERENCES emp.empires
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_enemyempires_enemy
|
||||
FOREIGN KEY (enemy_id) REFERENCES emp.empires
|
||||
ON DELETE CASCADE;
|
|
@ -0,0 +1,82 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Construction queues
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Buildings queues
|
||||
--
|
||||
|
||||
CREATE TABLE verse.bld_queues(
|
||||
planet_id INT NOT NULL PRIMARY KEY ,
|
||||
money REAL NOT NULL CHECK( money >= 0 ),
|
||||
work REAL NOT NULL CHECK( work >= 0 )
|
||||
);
|
||||
|
||||
ALTER TABLE verse.bld_queues
|
||||
ADD CONSTRAINT fk_bldqueues_planet
|
||||
FOREIGN KEY (planet_id) REFERENCES verse.planets;
|
||||
|
||||
|
||||
--
|
||||
-- Buildings queue items
|
||||
--
|
||||
|
||||
CREATE TABLE verse.bld_items(
|
||||
queue_id INT NOT NULL ,
|
||||
queue_order INT NOT NULL CHECK( queue_order >= 0 ) ,
|
||||
building_id INT NOT NULL ,
|
||||
destroy BOOLEAN NOT NULL ,
|
||||
amount INT NOT NULL CHECK( amount > 0 ) ,
|
||||
PRIMARY KEY( queue_id , queue_order )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_blditems_building
|
||||
ON verse.bld_items (building_id);
|
||||
|
||||
ALTER TABLE verse.bld_items
|
||||
ADD CONSTRAINT fk_blditems_queue
|
||||
FOREIGN KEY (queue_id) REFERENCES verse.bld_queues ,
|
||||
ADD CONSTRAINT fk_blditems_building
|
||||
FOREIGN KEY (building_id) REFERENCES tech.buildings;
|
||||
|
||||
|
||||
--
|
||||
-- Military queues
|
||||
--
|
||||
|
||||
CREATE TABLE verse.mil_queues(
|
||||
planet_id INT NOT NULL PRIMARY KEY ,
|
||||
money REAL NOT NULL CHECK( money >= 0 ),
|
||||
work REAL NOT NULL CHECK( work >= 0 )
|
||||
);
|
||||
|
||||
ALTER TABLE verse.mil_queues
|
||||
ADD CONSTRAINT fk_milqueues_planet
|
||||
FOREIGN KEY (planet_id) REFERENCES verse.planets;
|
||||
|
||||
|
||||
--
|
||||
-- Military queue items
|
||||
--
|
||||
|
||||
CREATE TABLE verse.mil_items(
|
||||
queue_id INT NOT NULL ,
|
||||
queue_order INT NOT NULL CHECK( queue_order >= 0 ) ,
|
||||
ship_id INT NOT NULL ,
|
||||
amount INT NOT NULL CHECK( amount > 0 ) ,
|
||||
PRIMARY KEY( queue_id , queue_order )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_militems_ship
|
||||
ON verse.mil_items (ship_id);
|
||||
|
||||
ALTER TABLE verse.mil_items
|
||||
ADD CONSTRAINT fk_militems_queue
|
||||
FOREIGN KEY (queue_id) REFERENCES verse.mil_queues ,
|
||||
ADD CONSTRAINT fk_militems_ship
|
||||
FOREIGN KEY (ship_id) REFERENCES tech.ships;
|
|
@ -0,0 +1,118 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Fleets
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Fleets
|
||||
--
|
||||
|
||||
CREATE TABLE fleets.fleets(
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY ,
|
||||
owner_id INT NOT NULL ,
|
||||
location_id INT NOT NULL ,
|
||||
name VARCHAR(64) ,
|
||||
attacking BOOLEAN NOT NULL ,
|
||||
status fleet_status NOT NULL ,
|
||||
penalty INT NOT NULL ,
|
||||
CHECK( ( status = 'AVAILABLE' AND penalty = 0 )
|
||||
OR ( status <> 'AVAILABLE' AND penalty > 0) )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_fleets_owner
|
||||
ON fleets.fleets ( owner_id );
|
||||
CREATE INDEX idx_fleets_location
|
||||
ON fleets.fleets ( location_id );
|
||||
CREATE INDEX idx_fleets_status
|
||||
ON fleets.fleets ( status , penalty );
|
||||
|
||||
ALTER TABLE fleets.fleets
|
||||
ADD CONSTRAINT fk_fleets_owner
|
||||
FOREIGN KEY ( owner_id ) REFERENCES emp.empires
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_fleets_location
|
||||
FOREIGN KEY ( location_id ) REFERENCES verse.planets;
|
||||
|
||||
|
||||
--
|
||||
-- Ships
|
||||
--
|
||||
|
||||
CREATE TABLE fleets.ships(
|
||||
fleet_id BIGINT NOT NULL ,
|
||||
ship_id INT NOT NULL ,
|
||||
amount INT NOT NULL CHECK( amount >= 0 ) ,
|
||||
damage REAL NOT NULL ,
|
||||
PRIMARY KEY( fleet_id , ship_id )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_ships_ship
|
||||
ON fleets.ships( ship_id );
|
||||
|
||||
ALTER TABLE fleets.ships
|
||||
ADD CONSTRAINT fk_ships_fleet
|
||||
FOREIGN KEY ( fleet_id ) REFERENCES fleets.fleets
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_ships_ship
|
||||
FOREIGN KEY ( ship_id ) REFERENCES tech.ships;
|
||||
|
||||
|
||||
--
|
||||
-- Fleet movements
|
||||
--
|
||||
|
||||
CREATE TABLE fleets.movements(
|
||||
fleet_id BIGINT NOT NULL PRIMARY KEY ,
|
||||
source_id INT NOT NULL ,
|
||||
time_left INT NOT NULL CHECK( time_left > 0 ) ,
|
||||
state_time_left INT NOT NULL CHECK( state_time_left > 0 )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_movements_source
|
||||
ON fleets.movements( source_id );
|
||||
|
||||
ALTER TABLE fleets.movements
|
||||
ADD CONSTRAINT fk_movements_fleet
|
||||
FOREIGN KEY ( fleet_id ) REFERENCES fleets.fleets
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_movements_source
|
||||
FOREIGN KEY ( source_id ) REFERENCES verse.planets;
|
||||
|
||||
|
||||
--
|
||||
-- Movement states, outer space
|
||||
--
|
||||
|
||||
CREATE TABLE fleets.ms_space(
|
||||
movement_id BIGINT NOT NULL PRIMARY KEY ,
|
||||
start_x REAL NOT NULL ,
|
||||
start_y REAL NOT NULL
|
||||
);
|
||||
|
||||
ALTER TABLE fleets.ms_space
|
||||
ADD CONSTRAINT fk_msspace_movement
|
||||
FOREIGN KEY ( movement_id ) REFERENCES fleets.movements
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Movement states, in system
|
||||
--
|
||||
|
||||
CREATE TABLE fleets.ms_system(
|
||||
movement_id BIGINT NOT NULL PRIMARY KEY ,
|
||||
ref_point_id INT NOT NULL ,
|
||||
outwards BOOLEAN NOT NULL ,
|
||||
past_ref_point BOOLEAN NOT NULL
|
||||
);
|
||||
|
||||
ALTER TABLE fleets.ms_system
|
||||
ADD CONSTRAINT fk_mssystem_movement
|
||||
FOREIGN KEY ( movement_id ) REFERENCES fleets.movements
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_mssystem_refpoint
|
||||
FOREIGN KEY ( ref_point_id ) REFERENCES verse.planets;
|
|
@ -0,0 +1,107 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- System & game updates status
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
--
|
||||
-- System status
|
||||
--
|
||||
CREATE TABLE sys.status(
|
||||
next_tick BIGINT NOT NULL
|
||||
DEFAULT 0 ,
|
||||
current_tick BIGINT ,
|
||||
|
||||
last_msg_recap TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( ) ,
|
||||
last_admin_recap TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( ) ,
|
||||
last_error_recap TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( ) ,
|
||||
|
||||
maintenance_start TIMESTAMP WITHOUT TIME ZONE ,
|
||||
maintenance_end TIMESTAMP WITHOUT TIME ZONE ,
|
||||
maintenance_text TEXT
|
||||
);
|
||||
|
||||
INSERT INTO sys.status DEFAULT VALUES;
|
||||
|
||||
GRANT SELECT ON sys.status TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Ticker status
|
||||
--
|
||||
|
||||
CREATE TYPE ticker_task_status
|
||||
AS ENUM( 'RUNNING' , 'STOPPED' , 'AUTO' );
|
||||
|
||||
CREATE TABLE sys.ticker(
|
||||
id SERIAL PRIMARY KEY ,
|
||||
task_name VARCHAR(64) NOT NULL UNIQUE ,
|
||||
status ticker_task_status NOT NULL ,
|
||||
auto_start TIMESTAMP WITHOUT TIME ZONE
|
||||
);
|
||||
|
||||
INSERT INTO sys.ticker( task_name , status )
|
||||
VALUES ( 'Game update' , 'STOPPED' );
|
||||
|
||||
GRANT SELECT ON sys.ticker TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Updates
|
||||
--
|
||||
CREATE TABLE sys.updates(
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY ,
|
||||
gu_type update_type NOT NULL ,
|
||||
status processing_status NOT NULL DEFAULT 'FUTURE' ,
|
||||
last_tick BIGINT NOT NULL DEFAULT -1
|
||||
);
|
||||
|
||||
CREATE INDEX idx_updates_finder
|
||||
ON sys.updates (gu_type, status, last_tick);
|
||||
|
||||
|
||||
--
|
||||
-- Planet updates
|
||||
--
|
||||
CREATE TABLE verse.updates(
|
||||
update_id BIGINT NOT NULL PRIMARY KEY ,
|
||||
planet_id INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_planetupdates_planet
|
||||
ON verse.updates (planet_id);
|
||||
|
||||
ALTER TABLE verse.updates
|
||||
ADD CONSTRAINT fk_planetupdates_update
|
||||
FOREIGN KEY ( update_id ) REFERENCES sys.updates ,
|
||||
ADD CONSTRAINT fk_planetupdates_planet
|
||||
FOREIGN KEY ( planet_id ) REFERENCES verse.planets;
|
||||
|
||||
|
||||
--
|
||||
-- Empire updates
|
||||
--
|
||||
CREATE TABLE emp.updates(
|
||||
update_id BIGINT NOT NULL PRIMARY KEY ,
|
||||
empire_id INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_empireupdates_empire
|
||||
ON emp.updates( empire_id );
|
||||
|
||||
ALTER TABLE emp.updates
|
||||
ADD CONSTRAINT fk_empireupdates_update
|
||||
FOREIGN KEY ( update_id ) REFERENCES sys.updates ,
|
||||
ADD CONSTRAINT fk_empireupdates_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE CASCADE;
|
|
@ -0,0 +1,126 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- System, user and administrative logs
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- System logs
|
||||
--
|
||||
CREATE TABLE sys.logs(
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY ,
|
||||
t TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( ) ,
|
||||
component VARCHAR( 64 ) ,
|
||||
level log_level NOT NULL ,
|
||||
message TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_syslogs_time
|
||||
ON sys.logs( t );
|
||||
CREATE INDEX idx_syslogs_component
|
||||
ON sys.logs( component );
|
||||
CREATE INDEX idx_syslogs_level
|
||||
ON sys.logs( level );
|
||||
|
||||
GRANT SELECT ON sys.logs TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- System logs, exceptions
|
||||
--
|
||||
CREATE TABLE sys.exceptions(
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY ,
|
||||
log_id BIGINT NOT NULL ,
|
||||
depth INT NOT NULL CHECK( depth>= 0 ) ,
|
||||
exc_class VARCHAR( 255 ) NOT NULL ,
|
||||
message TEXT
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_exceptions_logdepth
|
||||
ON sys.exceptions (log_id , depth );
|
||||
|
||||
ALTER TABLE sys.exceptions
|
||||
ADD CONSTRAINT fk_exceptions_log
|
||||
FOREIGN KEY ( log_id ) REFERENCES sys.logs
|
||||
ON DELETE CASCADE;
|
||||
|
||||
GRANT SELECT ON sys.exceptions TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- System logs, stack traces
|
||||
--
|
||||
CREATE TABLE sys.stack_traces(
|
||||
exception_id BIGSERIAL NOT NULL ,
|
||||
depth INT NOT NULL ,
|
||||
location TEXT ,
|
||||
file_name TEXT ,
|
||||
line_number INT ,
|
||||
PRIMARY KEY( exception_id , depth )
|
||||
);
|
||||
|
||||
ALTER TABLE sys.stack_traces
|
||||
ADD CONSTRAINT fk_stacktraces_exception
|
||||
FOREIGN KEY ( exception_id ) REFERENCES sys.exceptions
|
||||
ON DELETE CASCADE;
|
||||
|
||||
GRANT SELECT ON sys.stack_traces TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- User logs
|
||||
--
|
||||
CREATE TABLE users.logs(
|
||||
t TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( ) ,
|
||||
credentials_id INT NOT NULL ,
|
||||
level log_level NOT NULL ,
|
||||
message TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_userlogs_time
|
||||
ON users.logs( t );
|
||||
CREATE INDEX idx_userlogs_level
|
||||
ON users.logs( level );
|
||||
CREATE INDEX idx_userlogs_account
|
||||
ON users.logs( credentials_id );
|
||||
|
||||
ALTER TABLE users.logs
|
||||
ADD CONSTRAINT fk_userlogs_credentials
|
||||
FOREIGN KEY (credentials_id) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
GRANT SELECT ON users.logs TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Administrative logs
|
||||
--
|
||||
CREATE TABLE admin.logs(
|
||||
t TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( ) ,
|
||||
admin_id INT NOT NULL ,
|
||||
level log_level NOT NULL ,
|
||||
message TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_adminlogs_time
|
||||
ON admin.logs( t );
|
||||
CREATE INDEX idx_adminlogs_level
|
||||
ON admin.logs( level );
|
||||
CREATE INDEX idx_adminlogs_admin
|
||||
ON admin.logs( admin_id );
|
||||
|
||||
ALTER TABLE admin.logs
|
||||
ADD CONSTRAINT fk_userlogs_admin
|
||||
FOREIGN KEY (admin_id) REFERENCES admin.administrators;
|
||||
|
||||
|
||||
GRANT SELECT ON admin.logs TO :dbuser;
|
|
@ -0,0 +1,230 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Battles
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Status change types
|
||||
--
|
||||
|
||||
CREATE TYPE battle_planet_change
|
||||
AS ENUM( 'INIT' , 'RENAME', 'BUILD' , 'DESTROY' , 'BATTLE' );
|
||||
CREATE TYPE battle_fleet_change
|
||||
AS ENUM( 'INIT' , 'BUILD', 'ARRIVE' , 'DEPART' , 'DISBAND' , 'BATTLE' );
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Main battle table
|
||||
--
|
||||
|
||||
CREATE TABLE battles.battles(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
location_id INT NOT NULL ,
|
||||
first_tick BIGINT NOT NULL ,
|
||||
last_tick BIGINT
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_battles_uniqueness
|
||||
ON battles.battles( location_id , last_tick );
|
||||
|
||||
ALTER TABLE battles.battles
|
||||
ADD CONSTRAINT fk_battles_location
|
||||
FOREIGN KEY ( location_id ) REFERENCES verse.planets;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Battle planet status
|
||||
--
|
||||
|
||||
CREATE TABLE battles.planets(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
battle_id BIGINT NOT NULL ,
|
||||
tick_identifier BIGINT NOT NULL ,
|
||||
change_type battle_planet_change NOT NULL ,
|
||||
name VARCHAR(20)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_planets_tick
|
||||
ON battles.planets( tick_identifier );
|
||||
|
||||
CREATE UNIQUE INDEX idx_planets_uniquenes
|
||||
ON battles.planets( battle_id , tick_identifier , change_type );
|
||||
|
||||
ALTER TABLE battles.planets
|
||||
ADD CONSTRAINT fk_planets_battle
|
||||
FOREIGN KEY ( battle_id ) REFERENCES battles.battles
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Battle buildings
|
||||
--
|
||||
|
||||
CREATE TABLE battles.buildings(
|
||||
planet_id BIGINT NOT NULL ,
|
||||
building_id INT NOT NULL ,
|
||||
change INT NOT NULL CHECK( change <> 0 ) ,
|
||||
PRIMARY KEY( planet_id , building_id )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_buildings_building
|
||||
ON battles.buildings ( building_id );
|
||||
|
||||
ALTER TABLE battles.buildings
|
||||
ADD CONSTRAINT fk_buildings_planet
|
||||
FOREIGN KEY ( planet_id ) REFERENCES battles.planets
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_buildings_building
|
||||
FOREIGN KEY ( building_id ) REFERENCES tech.buildings;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Battle - planetary defence power
|
||||
--
|
||||
|
||||
CREATE TABLE battles.defences(
|
||||
battle_id BIGINT NOT NULL ,
|
||||
tick_identifier BIGINT NOT NULL ,
|
||||
power BIGINT NOT NULL ,
|
||||
PRIMARY KEY( battle_id , tick_identifier )
|
||||
);
|
||||
|
||||
ALTER TABLE battles.defences
|
||||
ADD CONSTRAINT fk_defences_battle
|
||||
FOREIGN KEY ( battle_id ) REFERENCES battles.battles
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Empires involved in a battle
|
||||
--
|
||||
|
||||
CREATE TABLE battles.empires(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
name VARCHAR(20) NOT NULL ,
|
||||
empire_id INT
|
||||
);
|
||||
|
||||
CREATE INDEX idx_empires_name
|
||||
ON battles.empires( name );
|
||||
|
||||
CREATE INDEX idx_empires_empire
|
||||
ON battles.empires( empire_id );
|
||||
|
||||
ALTER TABLE battles.empires
|
||||
ADD CONSTRAINT fk_empires_empire
|
||||
FOREIGN KEY (empire_id) REFERENCES emp.empires
|
||||
ON DELETE SET NULL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Protagonists
|
||||
--
|
||||
|
||||
CREATE TABLE battles.protagonists(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
battle_id BIGINT NOT NULL ,
|
||||
empire_id BIGINT NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_protagonists_uniqueness
|
||||
ON battles.protagonists( battle_id , empire_id );
|
||||
|
||||
CREATE INDEX idx_protagonists_empire
|
||||
ON battles.protagonists( empire_id );
|
||||
|
||||
ALTER TABLE battles.protagonists
|
||||
ADD CONSTRAINT fk_protagonists_battle
|
||||
FOREIGN KEY (battle_id) REFERENCES battles.battles
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_protagonists_empire
|
||||
FOREIGN KEY (empire_id) REFERENCES battles.empires;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Planet ownership
|
||||
--
|
||||
|
||||
CREATE TABLE battles.planet_ownership(
|
||||
protagonist_id BIGINT NOT NULL PRIMARY KEY ,
|
||||
abandoned_at BIGINT
|
||||
);
|
||||
|
||||
ALTER TABLE battles.planet_ownership
|
||||
ADD CONSTRAINT fk_ownership_protagonist
|
||||
FOREIGN KEY (protagonist_id) REFERENCES battles.protagonists
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Battle status changes
|
||||
--
|
||||
|
||||
CREATE TABLE battles.status_changes(
|
||||
protagonist_id BIGINT NOT NULL ,
|
||||
tick_identifier BIGINT NOT NULL ,
|
||||
attacking BOOLEAN NOT NULL ,
|
||||
PRIMARY KEY( protagonist_id , tick_identifier )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_statuschanges_tick
|
||||
ON battles.status_changes( tick_identifier );
|
||||
|
||||
ALTER TABLE battles.status_changes
|
||||
ADD CONSTRAINT fk_statuschanges_protagonist
|
||||
FOREIGN KEY (protagonist_id) REFERENCES battles.protagonists
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Fleets involved in battles
|
||||
--
|
||||
|
||||
CREATE TABLE battles.fleets(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
protagonist_id BIGINT NOT NULL ,
|
||||
tick_identifier BIGINT NOT NULL ,
|
||||
change_type battle_fleet_change NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_fleets_uniqueness
|
||||
ON battles.fleets( protagonist_id , tick_identifier , change_type );
|
||||
CREATE INDEX idx_fleets_tick
|
||||
ON battles.fleets( tick_identifier );
|
||||
|
||||
ALTER TABLE battles.fleets
|
||||
ADD CONSTRAINT fk_fleets_protagonist
|
||||
FOREIGN KEY (protagonist_id) REFERENCES battles.protagonists
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Ships in battle fleets
|
||||
--
|
||||
|
||||
CREATE TABLE battles.ships(
|
||||
fleet_id BIGINT NOT NULL ,
|
||||
ship_id INT NOT NULL ,
|
||||
change INT NOT NULL CHECK( change <> 0 )
|
||||
);
|
||||
|
||||
ALTER TABLE battles.ships
|
||||
ADD CONSTRAINT fk_ships_fleet
|
||||
FOREIGN KEY ( fleet_id ) REFERENCES battles.fleets
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_ships_ship
|
||||
FOREIGN KEY ( ship_id ) REFERENCES tech.ships;
|
|
@ -0,0 +1,311 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Storage of events (internal messages)
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TYPE event_type
|
||||
AS ENUM ( 'QUEUE' , 'EMPIRE' , 'FLEETS' , 'PLANET', 'ALLIANCE', 'ADMIN' , 'BUGS' );
|
||||
|
||||
CREATE TYPE event_status
|
||||
AS ENUM( 'TICK' , 'ACTION' , 'READY' , 'SENT' );
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Events table
|
||||
--
|
||||
|
||||
CREATE TABLE events.events(
|
||||
event_id BIGSERIAL PRIMARY KEY ,
|
||||
empire_id INT NOT NULL ,
|
||||
tick BIGINT NOT NULL ,
|
||||
real_time TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now() ,
|
||||
evt_type event_type NOT NULL ,
|
||||
evt_subtype INT NOT NULL ,
|
||||
status event_status NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_events_empire
|
||||
ON events.events (empire_id);
|
||||
|
||||
CREATE INDEX idx_events_time
|
||||
ON events.events (real_time);
|
||||
|
||||
CREATE INDEX idx_events_lookup
|
||||
ON events.events( empire_id , tick , evt_type , evt_subtype , status )
|
||||
WHERE status IN ( 'TICK' , 'ACTION' );
|
||||
|
||||
ALTER TABLE events.events
|
||||
ADD CONSTRAINT fk_events_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE CASCADE;
|
||||
|
||||
GRANT SELECT ON events.events TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Build queue events
|
||||
--
|
||||
|
||||
CREATE TABLE events.queue_events (
|
||||
event_id BIGINT NOT NULL PRIMARY KEY
|
||||
);
|
||||
|
||||
ALTER TABLE events.queue_events
|
||||
ADD CONSTRAINT fk_bqevents_event
|
||||
FOREIGN KEY (event_id) REFERENCES events.events
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Build queue event locations
|
||||
--
|
||||
|
||||
CREATE TABLE events.bqe_locations(
|
||||
event_id BIGINT NOT NULL ,
|
||||
location_id INT NOT NULL ,
|
||||
location_name VARCHAR(20) NOT NULL ,
|
||||
PRIMARY KEY( event_id , location_id )
|
||||
);
|
||||
|
||||
ALTER TABLE events.bqe_locations
|
||||
ADD CONSTRAINT fk_bqelocations_event
|
||||
FOREIGN KEY (event_id) REFERENCES events.queue_events
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_bqelocations_location
|
||||
FOREIGN KEY (location_id) REFERENCES verse.planets;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Empire events
|
||||
--
|
||||
|
||||
CREATE TABLE events.empire_events(
|
||||
event_id BIGINT NOT NULL PRIMARY KEY ,
|
||||
technology_id INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_empevents_tech
|
||||
ON events.empire_events (technology_id);
|
||||
|
||||
ALTER TABLE events.empire_events
|
||||
ADD CONSTRAINT fk_empevents_event
|
||||
FOREIGN KEY (event_id) REFERENCES events.events
|
||||
ON DELETE CASCADE,
|
||||
ADD CONSTRAINT fk_empevents_tech
|
||||
FOREIGN KEY (technology_id) REFERENCES tech.levels;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Fleet events
|
||||
--
|
||||
|
||||
CREATE TABLE events.fleets_events(
|
||||
event_id BIGINT NOT NULL PRIMARY KEY ,
|
||||
location_id INT NOT NULL ,
|
||||
location_name VARCHAR(20) NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_flevents_location
|
||||
ON events.fleets_events( location_id );
|
||||
|
||||
ALTER TABLE events.fleets_events
|
||||
ADD CONSTRAINT fk_flevents_event
|
||||
FOREIGN KEY (event_id) REFERENCES events.events
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_flevents_location
|
||||
FOREIGN KEY (location_id) REFERENCES verse.planets;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Fleets for fleet events
|
||||
--
|
||||
|
||||
CREATE TABLE events.fleet_lists(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
event_id BIGINT NOT NULL ,
|
||||
owner_id INT ,
|
||||
owner_name VARCHAR(20) NOT NULL ,
|
||||
fleet_name VARCHAR(64) ,
|
||||
fleet_power BIGINT NOT NULL CHECK( fleet_power > 0 ) ,
|
||||
status BOOLEAN ,
|
||||
source_id INT ,
|
||||
source_name VARCHAR(20) ,
|
||||
CHECK( source_id IS NULL AND source_name IS NULL OR source_id IS NOT NULL AND source_name IS NOT NULL )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_flelists_event
|
||||
ON events.fleet_lists( event_id );
|
||||
|
||||
CREATE INDEX idx_flelists_owner
|
||||
ON events.fleet_lists( owner_id )
|
||||
WHERE owner_id IS NOT NULL;
|
||||
|
||||
CREATE INDEX idx_flelists_source
|
||||
ON events.fleet_lists( source_id )
|
||||
WHERE source_id IS NOT NULL;
|
||||
|
||||
ALTER TABLE events.fleet_lists
|
||||
ADD CONSTRAINT fk_flelist_event
|
||||
FOREIGN KEY ( event_id ) REFERENCES events.fleets_events
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_flelist_owner
|
||||
FOREIGN KEY ( owner_id ) REFERENCES emp.empires
|
||||
ON DELETE SET NULL ,
|
||||
ADD CONSTRAINT fk_flelist_source
|
||||
FOREIGN KEY ( source_id ) REFERENCES verse.planets;
|
||||
|
||||
GRANT SELECT ON events.fleet_lists TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Planet events
|
||||
--
|
||||
|
||||
CREATE TABLE events.planet_events(
|
||||
event_id BIGINT PRIMARY KEY,
|
||||
location_id INT NOT NULL ,
|
||||
location_name VARCHAR(20) NOT NULL ,
|
||||
empire_id INT ,
|
||||
empire_name VARCHAR(20) ,
|
||||
battle_id BIGINT ,
|
||||
CHECK( battle_id IS NULL AND empire_id IS NULL AND empire_name IS NULL
|
||||
OR battle_id IS NOT NULL AND empire_id IS NULL AND empire_name IS NULL
|
||||
OR battle_id IS NULL AND empire_name IS NOT NULL )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_pevents_event
|
||||
ON events.planet_events ( event_id );
|
||||
|
||||
CREATE INDEX idx_pevents_location
|
||||
ON events.planet_events ( location_id );
|
||||
|
||||
CREATE INDEX idx_pevents_empire
|
||||
ON events.planet_events ( empire_id )
|
||||
WHERE empire_id IS NOT NULL;
|
||||
|
||||
CREATE INDEX idx_pevents_battle
|
||||
ON events.planet_events ( battle_id )
|
||||
WHERE battle_id IS NOT NULL;
|
||||
|
||||
ALTER TABLE events.planet_events
|
||||
ADD CONSTRAINT fk_pevents_event
|
||||
FOREIGN KEY ( event_id ) REFERENCES events.events
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_pevents_location
|
||||
FOREIGN KEY ( location_id ) REFERENCES verse.planets ,
|
||||
ADD CONSTRAINT fk_pevents_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE SET NULL ,
|
||||
ADD CONSTRAINT fk_pevents_battle
|
||||
FOREIGN KEY ( battle_id ) REFERENCES battles.battles;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Alliance events
|
||||
--
|
||||
|
||||
CREATE TABLE events.alliance_events(
|
||||
event_id BIGINT PRIMARY KEY ,
|
||||
alliance_id INT ,
|
||||
alliance_tag VARCHAR( 5 ) NOT NULL ,
|
||||
empire_id INT ,
|
||||
empire_name VARCHAR( 20 ) ,
|
||||
req_result BOOLEAN ,
|
||||
CHECK( req_result IS NULL AND empire_id IS NULL AND empire_name IS NULL
|
||||
OR req_result IS NOT NULL AND empire_id IS NULL AND empire_name IS NULL
|
||||
OR req_result IS NULL AND empire_name IS NOT NULL )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_aevents_event
|
||||
ON events.alliance_events ( event_id );
|
||||
|
||||
CREATE INDEX idx_aevents_alliance
|
||||
ON events.alliance_events ( alliance_id )
|
||||
WHERE alliance_id IS NOT NULL;
|
||||
|
||||
CREATE INDEX idx_aevents_empire
|
||||
ON events.alliance_events ( empire_id )
|
||||
WHERE empire_id IS NOT NULL;
|
||||
|
||||
ALTER TABLE events.alliance_events
|
||||
ADD CONSTRAINT fk_aevents_event
|
||||
FOREIGN KEY ( event_id ) REFERENCES events.events
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_aevents_allliance
|
||||
FOREIGN KEY ( alliance_id ) REFERENCES emp.alliances
|
||||
ON DELETE SET NULL ,
|
||||
ADD CONSTRAINT fk_aevents_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE SET NULL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Admin events
|
||||
--
|
||||
|
||||
CREATE TABLE events.admin_events(
|
||||
event_id BIGINT PRIMARY KEY ,
|
||||
n_warnings INT ,
|
||||
location_id INT ,
|
||||
old_name VARCHAR( 20 ) NOT NULL ,
|
||||
new_name VARCHAR( 20 )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_adevents_event
|
||||
ON events.admin_events ( event_id );
|
||||
|
||||
CREATE INDEX idx_adevents_location
|
||||
ON events.admin_events ( location_id )
|
||||
WHERE location_id IS NOT NULL;
|
||||
|
||||
ALTER TABLE events.admin_events
|
||||
ADD CONSTRAINT fk_adevents_event
|
||||
FOREIGN KEY ( event_id ) REFERENCES events.events
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_adevents_location
|
||||
FOREIGN KEY ( location_id ) REFERENCES verse.planets;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Bug tracking events
|
||||
--
|
||||
|
||||
CREATE TABLE events.bug_events(
|
||||
event_id BIGINT PRIMARY KEY ,
|
||||
bug_id BIGINT NOT NULL ,
|
||||
submitter_id BIGINT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_btevents_event
|
||||
ON events.bug_events ( event_id );
|
||||
|
||||
CREATE INDEX idx_btevents_bug
|
||||
ON events.bug_events ( bug_id );
|
||||
|
||||
CREATE INDEX idx_btevents_submitter
|
||||
ON events.bug_events ( submitter_id );
|
||||
|
||||
|
||||
ALTER TABLE events.bug_events
|
||||
ADD CONSTRAINT fk_btevents_event
|
||||
FOREIGN KEY ( event_id ) REFERENCES events.events
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_btevents_bug
|
||||
FOREIGN KEY ( bug_id ) REFERENCES bugs.initial_report_events ,
|
||||
ADD CONSTRAINT fk_btevents_submitter
|
||||
FOREIGN KEY ( submitter_id ) REFERENCES bugs.submitters;
|
|
@ -0,0 +1,235 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Storage of messages
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TYPE sender_type
|
||||
AS ENUM( 'ADM', 'EMP' );
|
||||
|
||||
CREATE TYPE receiver_type
|
||||
AS ENUM( 'ADM' , 'EMP' , 'ALL' );
|
||||
|
||||
CREATE TYPE message_status
|
||||
AS ENUM( 'UNREAD' , 'READ' , 'DELETED' );
|
||||
|
||||
|
||||
--
|
||||
-- Message senders
|
||||
--
|
||||
|
||||
CREATE TABLE msgs.senders(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
sender_type sender_type NOT NULL ,
|
||||
name VARCHAR(48) NOT NULL ,
|
||||
empire_id INT ,
|
||||
admin_id INT ,
|
||||
CHECK ( empire_id IS NULL AND admin_id IS NULL
|
||||
OR sender_type = 'ADM' AND empire_id IS NULL AND admin_id IS NOT NULL
|
||||
OR sender_type = 'EMP' AND empire_id IS NOT NULL AND admin_id IS NULL )
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_senders_empires
|
||||
ON msgs.senders ( empire_id )
|
||||
WHERE empire_id IS NOT NULL;
|
||||
|
||||
CREATE UNIQUE INDEX idx_senders_admins
|
||||
ON msgs.senders ( admin_id )
|
||||
WHERE admin_id IS NOT NULL;
|
||||
|
||||
ALTER TABLE msgs.senders
|
||||
ADD CONSTRAINT fk_senders_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE SET NULL ,
|
||||
ADD CONSTRAINT fk_senders_admin
|
||||
FOREIGN KEY ( admin_id ) REFERENCES admin.administrators
|
||||
ON DELETE SET NULL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Message receivers
|
||||
--
|
||||
|
||||
CREATE TABLE msgs.receivers(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
receiver_type receiver_type NOT NULL ,
|
||||
name VARCHAR(48) NOT NULL ,
|
||||
empire_id INT ,
|
||||
admin_id INT ,
|
||||
alliance_id INT ,
|
||||
CHECK ( empire_id IS NULL AND admin_id IS NULL AND alliance_id IS NULL
|
||||
OR receiver_type = 'ADM' AND empire_id IS NULL AND admin_id IS NOT NULL AND alliance_id IS NULL
|
||||
OR receiver_type = 'EMP' AND empire_id IS NOT NULL AND admin_id IS NULL AND alliance_id IS NULL
|
||||
OR receiver_type = 'ALL' AND empire_id IS NULL AND admin_id IS NULL AND alliance_id IS NOT NULL )
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_receivers_empires
|
||||
ON msgs.receivers ( empire_id )
|
||||
WHERE empire_id IS NOT NULL;
|
||||
|
||||
CREATE UNIQUE INDEX idx_receivers_admins
|
||||
ON msgs.receivers ( admin_id )
|
||||
WHERE admin_id IS NOT NULL;
|
||||
|
||||
CREATE UNIQUE INDEX idx_receivers_alliances
|
||||
ON msgs.receivers ( alliance_id )
|
||||
WHERE alliance_id IS NOT NULL;
|
||||
|
||||
ALTER TABLE msgs.receivers
|
||||
ADD CONSTRAINT fk_receivers_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE SET NULL ,
|
||||
ADD CONSTRAINT fk_receivers_alliance
|
||||
FOREIGN KEY ( alliance_id ) REFERENCES emp.alliances
|
||||
ON DELETE SET NULL ,
|
||||
ADD CONSTRAINT fk_receivers_admin
|
||||
FOREIGN KEY ( admin_id ) REFERENCES admin.administrators
|
||||
ON DELETE SET NULL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Text messages
|
||||
--
|
||||
|
||||
CREATE TABLE msgs.text_messages(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
tick BIGINT NOT NULL ,
|
||||
t TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL DEFAULT now( ) ,
|
||||
title VARCHAR( 64 ) NOT NULL ,
|
||||
contents TEXT NOT NULL
|
||||
);
|
||||
|
||||
GRANT SELECT ON msgs.text_messages TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Actual messages
|
||||
--
|
||||
|
||||
CREATE TABLE msgs.messages(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
receiver_id BIGINT NOT NULL ,
|
||||
sender_id BIGINT ,
|
||||
text_content_id BIGINT ,
|
||||
event_content_id BIGINT ,
|
||||
CHECK(
|
||||
sender_id IS NULL AND text_content_id IS NULL AND event_content_id IS NOT NULL
|
||||
OR sender_id IS NOT NULL AND text_content_id IS NOT NULL AND event_content_id IS NULL )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_messages_receiver
|
||||
ON msgs.messages( receiver_id );
|
||||
|
||||
CREATE UNIQUE INDEX idx_messages_e_event
|
||||
ON msgs.messages( event_content_id )
|
||||
WHERE event_content_id IS NOT NULL;
|
||||
|
||||
CREATE INDEX idx_messages_sender
|
||||
ON msgs.messages( sender_id )
|
||||
WHERE sender_id IS NOT NULL;
|
||||
|
||||
CREATE INDEX idx_messages_t_text
|
||||
ON msgs.messages( text_content_id )
|
||||
WHERE text_content_id IS NOT NULL;
|
||||
|
||||
ALTER TABLE msgs.messages
|
||||
ADD CONSTRAINT fk_messages_receiver
|
||||
FOREIGN KEY ( receiver_id ) REFERENCES msgs.receivers ,
|
||||
ADD CONSTRAINT fk_messages_sender
|
||||
FOREIGN KEY ( sender_id ) REFERENCES msgs.senders ,
|
||||
ADD CONSTRAINT fk_messages_text
|
||||
FOREIGN KEY ( text_content_id ) REFERENCES msgs.text_messages ,
|
||||
ADD CONSTRAINT fk_messages_event
|
||||
FOREIGN KEY ( event_content_id ) REFERENCES events.events
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Empire message delivery
|
||||
--
|
||||
|
||||
CREATE TABLE msgs.empire_delivery(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
empire_id INT NOT NULL ,
|
||||
message_id BIGINT NOT NULL ,
|
||||
in_inbox BOOLEAN NOT NULL ,
|
||||
status message_status NOT NULL ,
|
||||
emailed BOOLEAN NOT NULL ,
|
||||
recaped BOOLEAN NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_edelivery_empire
|
||||
ON msgs.empire_delivery ( empire_id );
|
||||
|
||||
CREATE UNIQUE INDEX idx_edelivery_message
|
||||
ON msgs.empire_delivery ( message_id , empire_id , in_inbox );
|
||||
|
||||
CREATE INDEX idx_edelivery_access
|
||||
ON msgs.empire_delivery ( empire_id , in_inbox , status );
|
||||
|
||||
CREATE INDEX idx_edelivery_status
|
||||
ON msgs.empire_delivery ( status , emailed , recaped );
|
||||
|
||||
ALTER TABLE msgs.empire_delivery
|
||||
ADD CONSTRAINT fk_edelivery_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_edelivery_message
|
||||
FOREIGN KEY ( message_id ) REFERENCES msgs.messages
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Admin message delivery
|
||||
--
|
||||
|
||||
CREATE TABLE msgs.admin_delivery(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
admin_id INT NOT NULL ,
|
||||
message_id BIGINT NOT NULL ,
|
||||
in_inbox BOOLEAN NOT NULL ,
|
||||
status message_status NOT NULL ,
|
||||
emailed BOOLEAN NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_adelivery_admin
|
||||
ON msgs.admin_delivery ( admin_id );
|
||||
|
||||
CREATE INDEX idx_adelivery_message
|
||||
ON msgs.admin_delivery ( message_id );
|
||||
|
||||
CREATE INDEX idx_adelivery_status
|
||||
ON msgs.admin_delivery ( status , emailed );
|
||||
|
||||
ALTER TABLE msgs.admin_delivery
|
||||
ADD CONSTRAINT fk_adelivery_admin
|
||||
FOREIGN KEY ( admin_id ) REFERENCES admin.administrators
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_adelivery_message
|
||||
FOREIGN KEY ( message_id ) REFERENCES msgs.messages;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- E-mail notification status
|
||||
--
|
||||
|
||||
CREATE TABLE msgs.email_notifications(
|
||||
account_id INT PRIMARY KEY ,
|
||||
last_sent TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL DEFAULT now()
|
||||
);
|
||||
|
||||
ALTER TABLE msgs.email_notifications
|
||||
ADD CONSTRAINT fk_emailnotifications_account
|
||||
FOREIGN KEY ( account_id ) REFERENCES users.active_accounts
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
Reference in a new issue