This repository has been archived on 2024-07-18. You can view files and clone it, but cannot push or open issues or pull requests.
lwb6/legacyworlds-server/legacyworlds-server-data/db-structure/parts/data/110-empires-data.sql

176 lines
3.7 KiB
MySQL
Raw Normal View History

2018-10-23 09:38:02 +02:00
-- 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 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;
--
-- 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;