Added full source code
This commit is contained in:
commit
33f8586698
1377 changed files with 123808 additions and 0 deletions
sql/beta5/structure
00-ecm-eccm.sql00-gdata.sql00-player-table.sql00-rule-base.sql00-system.sql01-alliance.sql01-message-base.sql01-planet.sql01-player-dipl.sql01-player-rules.sql01-research-base.sql02-alliance-forums.sql02-alliance-tech.sql02-orders.sql02-warehouse.sql03-fleets.sql04-sales.sql05-message-player.sql06-message-battle.sql06-message-internal.sql07-beacons.sql07-message-admin.sql10-ctf-tables.sql10-prot-tables.sql99-player-fk.sqlfinalise.sql
28
sql/beta5/structure/00-ecm-eccm.sql
Normal file
28
sql/beta5/structure/00-ecm-eccm.sql
Normal file
|
@ -0,0 +1,28 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/00-ecm-eccm.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Tables that store ECM and ECCM settings
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TABLE eccm (
|
||||
eccm_level SMALLINT NOT NULL,
|
||||
gain SMALLINT NOT NULL,
|
||||
probability SMALLINT NOT NULL,
|
||||
PRIMARY KEY (eccm_level, gain)
|
||||
);
|
||||
|
||||
CREATE TABLE ecm (
|
||||
ecm_level SMALLINT NOT NULL,
|
||||
info_level SMALLINT NOT NULL,
|
||||
probability SMALLINT NOT NULL,
|
||||
PRIMARY KEY (ecm_level, info_level)
|
||||
);
|
||||
|
||||
GRANT SELECT ON eccm TO legacyworlds;
|
||||
GRANT SELECT ON ecm TO legacyworlds;
|
18
sql/beta5/structure/00-gdata.sql
Normal file
18
sql/beta5/structure/00-gdata.sql
Normal file
|
@ -0,0 +1,18 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/00-gdata.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Table that stores game data
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TABLE gdata (
|
||||
id VARCHAR(8) PRIMARY KEY,
|
||||
value VARCHAR(60) NOT NULL
|
||||
);
|
||||
|
||||
GRANT INSERT,SELECT,UPDATE ON gdata TO legacyworlds;
|
42
sql/beta5/structure/00-player-table.sql
Normal file
42
sql/beta5/structure/00-player-table.sql
Normal file
|
@ -0,0 +1,42 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/00-player-table.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Table that stores player data, minus its foreign keys
|
||||
-- which will be defined in 99-player-fk.sql
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TABLE player (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
userid BIGINT NOT NULL REFERENCES main.account (id),
|
||||
name VARCHAR(15),
|
||||
quit INT,
|
||||
cash INT NOT NULL DEFAULT 20000,
|
||||
alliance INT,
|
||||
a_status CHAR(3) NULL CHECK(a_status IS NULL OR a_status IN ('REQ', 'IN')),
|
||||
a_grade BIGINT,
|
||||
a_vote BIGINT,
|
||||
first_planet BIGINT,
|
||||
restrain SMALLINT NOT NULL DEFAULT 10,
|
||||
research VARCHAR(8) NOT NULL DEFAULT '20!40!40',
|
||||
res_assistance BIGINT REFERENCES player (id),
|
||||
bh_unhappiness INT NOT NULL DEFAULT 0,
|
||||
probe_policy CHAR(4) NOT NULL DEFAULT '2110',
|
||||
hidden BOOLEAN NOT NULL DEFAULT FALSE
|
||||
);
|
||||
|
||||
CREATE INDEX player_alliance ON player (alliance);
|
||||
CREATE INDEX player_name ON player (name);
|
||||
CREATE INDEX player_userid ON player (userid);
|
||||
CREATE INDEX player_a_vote ON player (a_vote);
|
||||
CREATE INDEX player_a_grade ON player (a_grade);
|
||||
CREATE INDEX player_res_assistance ON player (res_assistance);
|
||||
CREATE INDEX player_first_planet ON player (first_planet);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE ON player TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON player_id_seq TO legacyworlds;
|
25
sql/beta5/structure/00-rule-base.sql
Normal file
25
sql/beta5/structure/00-rule-base.sql
Normal file
|
@ -0,0 +1,25 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/00-rule-base.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Base tables for the rule system
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
CREATE TABLE rule_def (
|
||||
name VARCHAR(32) NOT NULL PRIMARY KEY,
|
||||
value INT NOT NULL
|
||||
);
|
||||
|
||||
GRANT SELECT ON rule_def TO legacyworlds;
|
||||
|
||||
|
||||
CREATE TABLE rule_handler (
|
||||
rule VARCHAR(32) NOT NULL PRIMARY KEY REFERENCES rule_def (name),
|
||||
handler VARCHAR(32) NOT NULL
|
||||
);
|
||||
|
||||
GRANT SELECT ON rule_handler TO legacyworlds;
|
26
sql/beta5/structure/00-system.sql
Normal file
26
sql/beta5/structure/00-system.sql
Normal file
|
@ -0,0 +1,26 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/00-system.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Table that stores systems
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TABLE system (
|
||||
id SERIAL PRIMARY KEY,
|
||||
x INT NOT NULL,
|
||||
y INT NOT NULL,
|
||||
prot INT NOT NULL,
|
||||
assigned BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
nebula SMALLINT NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX system_coords ON system (x, y);
|
||||
CREATE INDEX system_prot ON system (prot);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE ON system TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON system_id_seq TO legacyworlds;
|
121
sql/beta5/structure/01-alliance.sql
Normal file
121
sql/beta5/structure/01-alliance.sql
Normal file
|
@ -0,0 +1,121 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/01-alliance.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Main alliance tables including definitions for an
|
||||
-- alliance itself as well as candidates for presidency
|
||||
-- and ranks
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TABLE alliance (
|
||||
id SERIAL NOT NULL PRIMARY KEY,
|
||||
tag VARCHAR(5) NOT NULL UNIQUE,
|
||||
name VARCHAR(64) NOT NULL,
|
||||
leader BIGINT REFERENCES player (id),
|
||||
successor BIGINT REFERENCES player (id),
|
||||
democracy BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
default_grade BIGINT NOT NULL,
|
||||
enable_tt CHAR(1) NOT NULL DEFAULT 'N' CHECK(enable_tt IN ('N', 'S', 'R'))
|
||||
);
|
||||
|
||||
CREATE INDEX alliance_leader ON alliance (leader);
|
||||
CREATE INDEX alliance_successor ON alliance (successor);
|
||||
CREATE INDEX alliance_def_grade ON alliance (default_grade);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON alliance TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON alliance_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Table for alliance ranks
|
||||
--
|
||||
-- list_access -> level of access to the alliance's listings
|
||||
-- NO - no access
|
||||
-- PY - member list
|
||||
-- PL - planet list
|
||||
-- PLD - detailed planet list
|
||||
--
|
||||
-- tech_trade -> level of access to the alliance's tech trading system
|
||||
-- NO - no access
|
||||
-- SL - submit tech list / view orders
|
||||
-- SR - submit tech list and requests / view orders
|
||||
-- VL - submit tech list and requests / view orders / view list
|
||||
-- MR - submit tech list and requests / view orders / view list / manage recommandations
|
||||
--
|
||||
|
||||
|
||||
CREATE TABLE alliance_grade (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
alliance INT REFERENCES alliance (id) ON DELETE CASCADE,
|
||||
name VARCHAR(32),
|
||||
list_access CHAR(3) NOT NULL DEFAULT 'PLD' CHECK(list_access IN ('NO','PY','PL','PLD')),
|
||||
attacks BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
can_set_grades BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
can_kick BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
can_accept BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
can_be_kicked BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
forum_admin BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
dipl_contact BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
can_vote BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
can_be_cand BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
tech_trade CHAR(2) NOT NULL DEFAULT 'NO' CHECK(tech_trade IN ('NO','SL','SR','VL','MR'))
|
||||
);
|
||||
|
||||
CREATE INDEX algr_alliance ON alliance_grade (alliance);
|
||||
ALTER TABLE alliance ADD FOREIGN KEY (default_grade) REFERENCES alliance_grade (id);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON alliance_grade TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON alliance_grade_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE algr_chgrade (
|
||||
grade BIGINT NOT NULL REFERENCES alliance_grade (id) ON DELETE CASCADE,
|
||||
can_change BIGINT NOT NULL REFERENCES alliance_grade (id) ON DELETE CASCADE,
|
||||
PRIMARY KEY (grade, can_change)
|
||||
);
|
||||
|
||||
CREATE INDEX algr_chgrade_target ON algr_chgrade (can_change);
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON algr_chgrade TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE algr_kick (
|
||||
grade BIGINT NOT NULL REFERENCES alliance_grade (id) ON DELETE CASCADE,
|
||||
kick BIGINT NOT NULL REFERENCES alliance_grade (id) ON DELETE CASCADE,
|
||||
PRIMARY KEY (grade, kick)
|
||||
);
|
||||
|
||||
CREATE INDEX algr_kick_target ON algr_kick (kick);
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON algr_kick TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE alliance_candidate (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
alliance INT NOT NULL REFERENCES alliance (id) ON DELETE CASCADE,
|
||||
candidate BIGINT NOT NULL REFERENCES player (id),
|
||||
UNIQUE (alliance, candidate)
|
||||
);
|
||||
|
||||
CREATE INDEX alcand_candidate ON alliance_candidate (candidate);
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON alliance_candidate TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON alliance_candidate_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Alliance status regarding the victory conditions
|
||||
-- in test match 1.
|
||||
--
|
||||
CREATE TABLE alliance_victory (
|
||||
alliance INT NOT NULL PRIMARY KEY REFERENCES alliance(id) ON DELETE CASCADE,
|
||||
time_of_victory INT NULL
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON alliance_victory TO legacyworlds;
|
45
sql/beta5/structure/01-message-base.sql
Normal file
45
sql/beta5/structure/01-message-base.sql
Normal file
|
@ -0,0 +1,45 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/01-message-base.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- The base tables for the PM system: messages and custom
|
||||
-- folders
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TABLE custom_folder (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
player BIGINT NOT NULL REFERENCES player (id),
|
||||
name VARCHAR(32) NOT NULL,
|
||||
UNIQUE (player, name)
|
||||
);
|
||||
|
||||
GRANT INSERT,SELECT,UPDATE,DELETE ON custom_folder TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON custom_folder_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE message (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
player BIGINT NOT NULL REFERENCES player (id),
|
||||
sent_on INT NOT NULL,
|
||||
mtype VARCHAR(16) NOT NULL,
|
||||
ftype CHAR(3) NOT NULL CHECK(ftype IN ('IN','INT','OUT','CUS')),
|
||||
fcustom BIGINT REFERENCES custom_folder (id) ON DELETE SET NULL,
|
||||
is_new BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
deleted BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
original BIGINT REFERENCES message (id),
|
||||
reply_to BIGINT REFERENCES message (id)
|
||||
);
|
||||
|
||||
CREATE INDEX message_player ON message (player);
|
||||
CREATE INDEX message_fcustom ON message (fcustom);
|
||||
CREATE INDEX message_reply_to ON message (reply_to);
|
||||
CREATE INDEX message_original ON message (original);
|
||||
|
||||
GRANT INSERT,SELECT,UPDATE ON message TO legacyworlds;
|
||||
GRANT INSERT,SELECT,UPDATE ON message_id_seq TO legacyworlds;
|
139
sql/beta5/structure/01-planet.sql
Normal file
139
sql/beta5/structure/01-planet.sql
Normal file
|
@ -0,0 +1,139 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/01-planet.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Planet data and associated tables (buildqueue, etc...)
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TABLE planet (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
owner BIGINT REFERENCES player (id),
|
||||
system INT NOT NULL REFERENCES system (id),
|
||||
orbit SMALLINT NOT NULL CHECK(orbit BETWEEN 0 AND 5),
|
||||
name VARCHAR(15) NOT NULL UNIQUE,
|
||||
status SMALLINT NOT NULL DEFAULT 0 CHECK(status BETWEEN 0 AND 5),
|
||||
pop INT NOT NULL DEFAULT 2000,
|
||||
max_pop INT NOT NULL,
|
||||
ifact INT NOT NULL DEFAULT 3,
|
||||
mfact INT NOT NULL DEFAULT 3,
|
||||
turrets INT NOT NULL DEFAULT 0,
|
||||
renamed INT NOT NULL DEFAULT 0,
|
||||
happiness SMALLINT NOT NULL DEFAULT 70 CHECK(happiness BETWEEN 0 AND 100),
|
||||
beacon SMALLINT NOT NULL DEFAULT 0,
|
||||
abandon SMALLINT,
|
||||
bh_prep SMALLINT,
|
||||
bh_unhappiness SMALLINT NOT NULL DEFAULT 0,
|
||||
sale SMALLINT,
|
||||
built_probe BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
probe_policy CHAR(4),
|
||||
corruption SMALLINT NOT NULL DEFAULT 0,
|
||||
vacation CHAR(4) NOT NULL DEFAULT 'NO' CHECK(vacation IN ('NO','PEND','YES')),
|
||||
mod_check BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
force_rename INT,
|
||||
UNIQUE (system, orbit)
|
||||
);
|
||||
|
||||
CREATE INDEX planet_owner ON planet (owner);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE ON planet TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON planet_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
CREATE TABLE planet_abandon_time (
|
||||
id BIGINT PRIMARY KEY REFERENCES planet (id),
|
||||
time_required INT NOT NULL CHECK(time_required BETWEEN 6 AND 24)
|
||||
);
|
||||
|
||||
CREATE INDEX planet_abandon_time_req ON planet_abandon_time (time_required);
|
||||
GRANT SELECT,INSERT,DELETE,UPDATE ON planet_abandon_time TO legacyworlds;
|
||||
|
||||
|
||||
CREATE TABLE planet_max_pop (
|
||||
planet BIGINT NOT NULL REFERENCES planet(id),
|
||||
tech_level SMALLINT NOT NULL CHECK(tech_level BETWEEN 0 AND 3),
|
||||
max_pop INT NOT NULL,
|
||||
PRIMARY KEY (planet, tech_level)
|
||||
);
|
||||
GRANT SELECT,INSERT,DELETE ON planet_max_pop TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE facthist (
|
||||
planet BIGINT NOT NULL REFERENCES planet (id),
|
||||
moment INT NOT NULL DEFAULT INT4(EXTRACT(EPOCH FROM NOW())),
|
||||
is_military BOOLEAN NOT NULL,
|
||||
change INT NOT NULL CHECK(change <> 0)
|
||||
);
|
||||
|
||||
CREATE INDEX facthist_idx ON facthist (planet, moment, is_military);
|
||||
GRANT SELECT,INSERT,DELETE ON facthist TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE turhist (
|
||||
planet BIGINT NOT NULL REFERENCES planet (id),
|
||||
moment INT NOT NULL DEFAULT INT4(EXTRACT(EPOCH FROM NOW())),
|
||||
change INT NOT NULL CHECK(change <> 0)
|
||||
);
|
||||
|
||||
CREATE INDEX turhist_idx ON turhist (planet, moment);
|
||||
GRANT SELECT,INSERT,DELETE ON turhist TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE buildqueue (
|
||||
planet BIGINT NOT NULL REFERENCES planet (id),
|
||||
bq_order INT NOT NULL CHECK(bq_order >= 0),
|
||||
item SMALLINT NOT NULL CHECK(item BETWEEN 0 AND 5),
|
||||
quantity INT NOT NULL CHECK(quantity > 0),
|
||||
workunits BIGINT NOT NULL DEFAULT 0 CHECK(workunits >= 0),
|
||||
PRIMARY KEY (planet, bq_order)
|
||||
);
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON buildqueue TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE abandon_log (
|
||||
planet BIGINT NOT NULL REFERENCES planet (id),
|
||||
abandon_time INT NOT NULL DEFAULT INT4(EXTRACT(EPOCH FROM NOW())),
|
||||
former_owner BIGINT NOT NULL REFERENCES player (id),
|
||||
retake_time INT,
|
||||
retake_owner BIGINT REFERENCES player (id),
|
||||
PRIMARY KEY (planet, abandon_time)
|
||||
);
|
||||
|
||||
CREATE INDEX abandon_former ON abandon_log (former_owner);
|
||||
CREATE INDEX abandon_retake ON abandon_log (retake_owner);
|
||||
|
||||
GRANT INSERT,UPDATE,SELECT ON abandon_log TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE attacks (
|
||||
planet BIGINT NOT NULL REFERENCES planet (id) PRIMARY KEY,
|
||||
ecm_level SMALLINT NOT NULL CHECK(ecm_level BETWEEN 0 AND 4),
|
||||
eccm_level SMALLINT NOT NULL CHECK(ecm_level BETWEEN 0 AND 4),
|
||||
friendly INT NOT NULL,
|
||||
enemy INT NOT NULL,
|
||||
v_players BOOLEAN NOT NULL,
|
||||
v_friendly INT,
|
||||
v_enemy INT
|
||||
);
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON attacks TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Table to store planet names for new players
|
||||
--
|
||||
|
||||
CREATE TABLE planet_reg_queue (
|
||||
account BIGINT NOT NULL PRIMARY KEY REFERENCES main.reg_queue (account)
|
||||
ON DELETE CASCADE,
|
||||
p_name VARCHAR(15) NOT NULL UNIQUE
|
||||
);
|
||||
GRANT SELECT,INSERT,DELETE ON planet_reg_queue TO legacyworlds;
|
89
sql/beta5/structure/01-player-dipl.sql
Normal file
89
sql/beta5/structure/01-player-dipl.sql
Normal file
|
@ -0,0 +1,89 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/01-player-dipl.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Data structures that store everything related to a
|
||||
-- player's diplomatic relations
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TABLE research_assistance (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
player BIGINT NOT NULL REFERENCES player (id),
|
||||
price INT NOT NULL CHECK(price >= 0),
|
||||
offer_to BIGINT NOT NULL REFERENCES player (id),
|
||||
technology INT REFERENCES research (id),
|
||||
moment INT NOT NULL DEFAULT INT4(EXTRACT(EPOCH FROM NOW())),
|
||||
accepted BOOLEAN
|
||||
);
|
||||
|
||||
CREATE INDEX res_as_player ON research_assistance (player);
|
||||
CREATE INDEX res_as_offer_to ON research_assistance (offer_to);
|
||||
CREATE INDEX res_as_technology ON research_assistance (technology);
|
||||
CREATE INDEX res_as_moment ON research_assistance (moment);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE ON research_assistance TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON research_assistance_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE enemy_alliance (
|
||||
player BIGINT NOT NULL REFERENCES player (id),
|
||||
alliance INT NOT NULL REFERENCES alliance (id) ON DELETE CASCADE,
|
||||
PRIMARY KEY (player, alliance)
|
||||
);
|
||||
|
||||
CREATE INDEX enemy_alliance_idx ON enemy_alliance (alliance);
|
||||
GRANT SELECT,INSERT,DELETE ON enemy_alliance TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE enemy_player (
|
||||
player BIGINT NOT NULL REFERENCES player (id),
|
||||
enemy BIGINT NOT NULL REFERENCES player (id),
|
||||
PRIMARY KEY (player, enemy)
|
||||
);
|
||||
|
||||
CREATE INDEX enemy_player_idx ON enemy_player (enemy);
|
||||
GRANT SELECT,INSERT,DELETE ON enemy_player TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE trusted (
|
||||
player BIGINT NOT NULL REFERENCES player (id),
|
||||
level SMALLINT NOT NULL CHECK(level >= 0),
|
||||
friend BIGINT NOT NULL REFERENCES player (id),
|
||||
PRIMARY KEY (player, level),
|
||||
UNIQUE (player, level)
|
||||
);
|
||||
GRANT SELECT,INSERT,DELETE,UPDATE ON trusted TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE trusted_ban (
|
||||
player BIGINT NOT NULL REFERENCES player (id),
|
||||
ban_player BIGINT NOT NULL REFERENCES player (id),
|
||||
PRIMARY KEY (player, ban_player)
|
||||
);
|
||||
|
||||
CREATE INDEX trusted_ban_idx ON trusted_ban (ban_player);
|
||||
GRANT SELECT,INSERT,DELETE ON trusted_ban TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE donation_log (
|
||||
time INT NOT NULL DEFAULT UNIX_TIMESTAMP(NOW()),
|
||||
source BIGINT NOT NULL REFERENCES player (id),
|
||||
target BIGINT NOT NULL REFERENCES player (id),
|
||||
amount INT NOT NULL CHECK(amount > 0),
|
||||
PRIMARY KEY (time, source)
|
||||
);
|
||||
|
||||
CREATE INDEX donation_source ON donation_log (source);
|
||||
CREATE INDEX donation_target ON donation_log (target);
|
||||
|
||||
GRANT INSERT,SELECT ON donation_log TO legacyworlds;
|
40
sql/beta5/structure/01-player-rules.sql
Normal file
40
sql/beta5/structure/01-player-rules.sql
Normal file
|
@ -0,0 +1,40 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/01-player-rules.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Data structures that store the rules that apply for
|
||||
-- each player, as well as the list of implemented techs
|
||||
-- for each player
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TABLE research_player (
|
||||
player BIGINT NOT NULL REFERENCES player (id),
|
||||
research INT NOT NULL REFERENCES research (id),
|
||||
possible BOOLEAN NOT NULL,
|
||||
in_effect SMALLINT NOT NULL DEFAULT 0,
|
||||
points INT NOT NULL DEFAULT 0 CHECK(points >= 0),
|
||||
given_by BIGINT REFERENCES player (id),
|
||||
PRIMARY KEY (player, research)
|
||||
);
|
||||
|
||||
CREATE INDEX resplayer_research ON research_player (research);
|
||||
CREATE INDEX resplayer_giver ON research_player (given_by);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON research_player TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE rule (
|
||||
name VARCHAR(32) NOT NULL REFERENCES rule_def (name),
|
||||
player BIGINT NOT NULL REFERENCES player (id),
|
||||
value INT NOT NULL,
|
||||
PRIMARY KEY (name, player)
|
||||
);
|
||||
|
||||
CREATE INDEX rule_player ON rule (player);
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON rule TO legacyworlds;
|
59
sql/beta5/structure/01-research-base.sql
Normal file
59
sql/beta5/structure/01-research-base.sql
Normal file
|
@ -0,0 +1,59 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/01-research-base.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Tables that store tech definitions and functions to
|
||||
-- ease inserting the data
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
-- Research definitions
|
||||
CREATE TABLE research (
|
||||
id INT NOT NULL PRIMARY KEY,
|
||||
points INT NOT NULL,
|
||||
cost INT NOT NULL,
|
||||
optional SMALLINT NOT NULL CHECK(optional IN (0,1,2)),
|
||||
category SMALLINT NOT NULL CHECK(category IN (0,1,2)),
|
||||
is_law BOOLEAN NOT NULL
|
||||
);
|
||||
|
||||
GRANT SELECT ON research TO legacyworlds;
|
||||
|
||||
|
||||
-- Dependencies
|
||||
CREATE TABLE research_dep (
|
||||
research INT NOT NULL REFERENCES research (id),
|
||||
depends_on INT NOT NULL REFERENCES research (id),
|
||||
PRIMARY KEY (research, depends_on)
|
||||
);
|
||||
|
||||
CREATE INDEX research_depends_on ON research_dep (depends_on);
|
||||
GRANT SELECT ON research_dep TO legacyworlds;
|
||||
|
||||
|
||||
-- Research names and descriptions
|
||||
CREATE TABLE research_txt (
|
||||
research INT NOT NULL REFERENCES research (id),
|
||||
lang VARCHAR(4) NOT NULL REFERENCES main.lang (txt),
|
||||
name VARCHAR(64) NOT NULL,
|
||||
description TEXT NOT NULL,
|
||||
PRIMARY KEY (research, lang)
|
||||
);
|
||||
|
||||
CREATE INDEX research_txt_lang ON research_txt (lang);
|
||||
GRANT SELECT ON research_txt TO legacyworlds;
|
||||
|
||||
|
||||
-- Research effects
|
||||
CREATE TABLE research_effect (
|
||||
research INT NOT NULL REFERENCES research (id),
|
||||
rule VARCHAR(32) NOT NULL REFERENCES rule_def (name),
|
||||
modifier INT NOT NULL,
|
||||
PRIMARY KEY (research, rule)
|
||||
);
|
||||
|
||||
CREATE INDEX research_fx_rule ON research_effect (rule);
|
||||
GRANT SELECT ON research_effect TO legacyworlds;
|
100
sql/beta5/structure/02-alliance-forums.sql
Normal file
100
sql/beta5/structure/02-alliance-forums.sql
Normal file
|
@ -0,0 +1,100 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/02-alliance-forums.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Tables for alliance forums
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TABLE af_forum (
|
||||
id SERIAL PRIMARY KEY,
|
||||
alliance INT NOT NULL REFERENCES alliance(id) ON DELETE CASCADE,
|
||||
forder INT NOT NULL CHECK(forder >= 0),
|
||||
title VARCHAR(64) NOT NULL,
|
||||
description TEXT,
|
||||
topics INT NOT NULL DEFAULT 0 CHECK(topics >= 0),
|
||||
posts INT NOT NULL DEFAULT 0 CHECK(posts >= 0),
|
||||
last_post BIGINT,
|
||||
user_post BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
UNIQUE(alliance, forder),
|
||||
UNIQUE(alliance, title)
|
||||
);
|
||||
|
||||
CREATE INDEX af_forum_last_post ON af_forum (last_post);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON af_forum TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON af_forum_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE af_topic (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
forum INT NOT NULL REFERENCES af_forum (id) ON DELETE CASCADE,
|
||||
first_post BIGINT NOT NULL,
|
||||
last_post BIGINT,
|
||||
sticky BOOLEAN NOT NULL DEFAULT FALSE
|
||||
);
|
||||
|
||||
CREATE INDEX af_topic_forum ON af_topic (forum);
|
||||
CREATE INDEX af_topic_first_post ON af_topic (first_post);
|
||||
CREATE INDEX af_topic_last_post ON af_topic (last_post);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON af_topic TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON af_topic_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE af_post (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
forum INT NOT NULL REFERENCES af_forum (id) ON DELETE CASCADE,
|
||||
topic BIGINT REFERENCES af_topic (id) ON DELETE CASCADE,
|
||||
author BIGINT NOT NULL REFERENCES player (id),
|
||||
reply_to BIGINT REFERENCES af_post (id) ON DELETE NO ACTION,
|
||||
moment INT NOT NULL DEFAULT INT4(EXTRACT(EPOCH FROM NOW())),
|
||||
title VARCHAR(100) NOT NULL,
|
||||
contents TEXT NOT NULL,
|
||||
enable_code BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
enable_smileys BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
edited INT,
|
||||
edited_by BIGINT REFERENCES player(id)
|
||||
);
|
||||
|
||||
CREATE INDEX af_post_forum ON af_post (forum);
|
||||
CREATE INDEX af_post_topic ON af_post (topic);
|
||||
CREATE INDEX af_post_author ON af_post (author);
|
||||
CREATE INDEX af_post_reply_to ON af_post (reply_to);
|
||||
CREATE INDEX af_post_edited_by ON af_post (edited_by);
|
||||
|
||||
ALTER TABLE af_forum ADD FOREIGN KEY (last_post) REFERENCES af_post (id) ON DELETE SET NULL;
|
||||
ALTER TABLE af_topic ADD FOREIGN KEY (first_post) REFERENCES af_post (id) ON DELETE CASCADE;
|
||||
ALTER TABLE af_topic ADD FOREIGN KEY (last_post) REFERENCES af_post (id) ON DELETE SET NULL;
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON af_post TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON af_post_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE af_read (
|
||||
reader BIGINT NOT NULL REFERENCES player (id),
|
||||
topic BIGINT NOT NULL REFERENCES af_topic (id) ON DELETE CASCADE,
|
||||
PRIMARY KEY (reader, topic)
|
||||
);
|
||||
|
||||
CREATE INDEX af_read_topic ON af_read (topic);
|
||||
GRANT SELECT,INSERT,DELETE ON af_read TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE algr_forums (
|
||||
grade BIGINT NOT NULL REFERENCES alliance_grade (id) ON DELETE CASCADE,
|
||||
forum INT NOT NULL REFERENCES af_forum (id) ON DELETE CASCADE,
|
||||
is_mod BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
PRIMARY KEY (grade, forum)
|
||||
);
|
||||
|
||||
CREATE INDEX algr_forums_forum ON algr_forums (forum);
|
||||
GRANT SELECT,INSERT,DELETE,UPDATE ON algr_forums TO legacyworlds;
|
81
sql/beta5/structure/02-alliance-tech.sql
Normal file
81
sql/beta5/structure/02-alliance-tech.sql
Normal file
|
@ -0,0 +1,81 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/02-alliance-tech.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Tables for the alliance technology trading tool.
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Table tech_trade_list
|
||||
--
|
||||
-- Contains the lists for all players in an alliance
|
||||
--
|
||||
-- status: indicates the player's status w/r to a tech
|
||||
-- N - New technology
|
||||
-- L - Law
|
||||
-- I - Implemented technology
|
||||
-- F - Foreseen breakthrough
|
||||
--
|
||||
|
||||
CREATE TABLE tech_trade_list (
|
||||
alliance INT NOT NULL REFERENCES alliance (id) ON DELETE CASCADE,
|
||||
member BIGINT NOT NULL REFERENCES player (id) ON DELETE CASCADE,
|
||||
tech INT NOT NULL REFERENCES research (id),
|
||||
submitted INT NOT NULL DEFAULT UNIX_TIMESTAMP( NOW() ),
|
||||
status CHAR(1) NOT NULL CHECK(status IN ('N', 'L', 'I', 'F')),
|
||||
PRIMARY KEY(member, tech)
|
||||
);
|
||||
|
||||
CREATE INDEX tech_trade_list_alliance ON tech_trade_list (alliance);
|
||||
CREATE INDEX tech_trade_list_tech ON tech_trade_list (tech);
|
||||
|
||||
GRANT INSERT,SELECT,DELETE ON tech_trade_list TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Table tech_trade_request
|
||||
--
|
||||
-- Contains the list of requests made by alliance members
|
||||
--
|
||||
|
||||
CREATE TABLE tech_trade_request (
|
||||
alliance INT NOT NULL REFERENCES alliance (id) ON DELETE CASCADE,
|
||||
player BIGINT NOT NULL REFERENCES player (id) ON DELETE CASCADE,
|
||||
priority INT NOT NULL CHECK(priority BETWEEN 0 AND 6),
|
||||
tech INT NOT NULL REFERENCES research (id),
|
||||
|
||||
PRIMARY KEY(player, priority),
|
||||
UNIQUE(player, tech)
|
||||
);
|
||||
|
||||
CREATE INDEX tech_trade_req_alliance ON tech_trade_request (alliance);
|
||||
CREATE INDEX tech_trade_req_tech ON tech_trade_request (tech);
|
||||
|
||||
GRANT INSERT,SELECT,DELETE,UPDATE ON tech_trade_request TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Table tech_trade_order
|
||||
--
|
||||
-- Contains the orders issued for tech trades
|
||||
--
|
||||
|
||||
CREATE TABLE tech_trade_order (
|
||||
alliance INT NOT NULL REFERENCES alliance (id) ON DELETE CASCADE,
|
||||
player BIGINT NOT NULL REFERENCES player (id) ON DELETE CASCADE,
|
||||
send_to BIGINT NOT NULL UNIQUE REFERENCES player (id) ON DELETE CASCADE,
|
||||
tech INT NOT NULL REFERENCES research (id),
|
||||
submitted INT NOT NULL DEFAULT UNIX_TIMESTAMP( NOW() ),
|
||||
obeyed INT,
|
||||
PRIMARY KEY(player)
|
||||
);
|
||||
|
||||
CREATE INDEX tech_trade_order_tech ON tech_trade_order (tech);
|
||||
CREATE INDEX tech_trade_order_alliance ON tech_trade_order (alliance);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON tech_trade_order TO legacyworlds;
|
57
sql/beta5/structure/02-orders.sql
Normal file
57
sql/beta5/structure/02-orders.sql
Normal file
|
@ -0,0 +1,57 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/02-orders.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Data structures for moving objects and hyperspace
|
||||
-- stand-by
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TABLE hs_wait (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
time_left INT NOT NULL CHECK(time_left BETWEEN 0 AND 48),
|
||||
time_spent INT NOT NULL DEFAULT 0 CHECK(time_spent >= 0),
|
||||
origin BIGINT REFERENCES planet (id),
|
||||
drop_point BIGINT NOT NULL REFERENCES planet (id)
|
||||
);
|
||||
|
||||
CREATE INDEX wait_origin ON hs_wait (origin);
|
||||
CREATE INDEX wait_drop_point ON hs_wait (drop_point);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON hs_wait TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON hs_wait_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE moving_object (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
m_from BIGINT NOT NULL REFERENCES planet (id),
|
||||
m_to BIGINT NOT NULL REFERENCES planet (id),
|
||||
changed SMALLINT NOT NULL DEFAULT 0 CHECK(changed >= 0),
|
||||
time_left INT NOT NULL CHECK(time_left >= 0),
|
||||
hyperspace BOOLEAN NOT NULL,
|
||||
wait_order BIGINT REFERENCES hs_wait (id) ON DELETE SET NULL
|
||||
);
|
||||
|
||||
CREATE INDEX move_from ON moving_object (m_from);
|
||||
CREATE INDEX move_to ON moving_object (m_to);
|
||||
CREATE INDEX move_hssb ON moving_object (wait_order);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON moving_object TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON moving_object_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE waypoint (
|
||||
move_id BIGINT NOT NULL REFERENCES moving_object (id) ON DELETE CASCADE,
|
||||
location BIGINT NOT NULL REFERENCES planet (id),
|
||||
until_eta INT NOT NULL CHECK(until_eta >= 0),
|
||||
PRIMARY KEY (move_id, until_eta)
|
||||
);
|
||||
|
||||
CREATE INDEX waypoint_location ON waypoint (location);
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON waypoint TO legacyworlds;
|
70
sql/beta5/structure/02-warehouse.sql
Normal file
70
sql/beta5/structure/02-warehouse.sql
Normal file
|
@ -0,0 +1,70 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/02-warehouse.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- The tables in which the day ticks store the game's
|
||||
-- history
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
CREATE TABLE bt_debug (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
tick_time INT NOT NULL DEFAULT UNIX_TIMESTAMP(NOW()),
|
||||
txt TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX bt_time ON bt_debug (tick_time);
|
||||
CREATE RULE bt_debug_cleaner AS
|
||||
ON INSERT TO bt_debug DO ALSO
|
||||
DELETE FROM bt_debug WHERE UNIX_TIMESTAMP(NOW()) - tick_time > 3 * 86400;
|
||||
GRANT INSERT,DELETE ON bt_debug TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON bt_debug_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE warehouse (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
player BIGINT NOT NULL REFERENCES player (id),
|
||||
tick_at INT NOT NULL DEFAULT UNIX_TIMESTAMP(NOW()),
|
||||
cash BIGINT NOT NULL,
|
||||
a_tag VARCHAR(5),
|
||||
g_rank BIGINT NOT NULL,
|
||||
c_rank BIGINT NOT NULL,
|
||||
m_rank BIGINT NOT NULL,
|
||||
f_rank BIGINT NOT NULL,
|
||||
d_rank BIGINT NOT NULL,
|
||||
o_rank BIGINT,
|
||||
gaships INT NOT NULL,
|
||||
fighters INT NOT NULL,
|
||||
cruisers INT NOT NULL,
|
||||
bcruisers INT NOT NULL,
|
||||
fleet INT NOT NULL,
|
||||
tech_list TEXT NOT NULL,
|
||||
tech_points BIGINT NOT NULL,
|
||||
UNIQUE (player, tick_at)
|
||||
);
|
||||
|
||||
GRANT INSERT,SELECT,DELETE ON warehouse TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON warehouse_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE wh_planet (
|
||||
id BIGINT NOT NULL REFERENCES warehouse (id) ON DELETE CASCADE,
|
||||
planet BIGINT NOT NULL REFERENCES planet (id),
|
||||
name VARCHAR(15) NOT NULL,
|
||||
pop INT NOT NULL,
|
||||
max_pop INT NOT NULL,
|
||||
ifact INT NOT NULL,
|
||||
mfact INT NOT NULL,
|
||||
turrets INT NOT NULL,
|
||||
happiness SMALLINT NOT NULL,
|
||||
beacon SMALLINT NOT NULL,
|
||||
abandon SMALLINT,
|
||||
corruption INT,
|
||||
PRIMARY KEY (id, planet)
|
||||
);
|
||||
GRANT INSERT,SELECT,DELETE ON wh_planet TO legacyworlds;
|
38
sql/beta5/structure/03-fleets.sql
Normal file
38
sql/beta5/structure/03-fleets.sql
Normal file
|
@ -0,0 +1,38 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/03-fleets.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- The table that containst fleet-related data
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TABLE fleet (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
owner BIGINT NOT NULL REFERENCES player (id),
|
||||
name VARCHAR(64) NOT NULL DEFAULT 'No Name',
|
||||
location BIGINT REFERENCES planet (id),
|
||||
gaships INT NOT NULL DEFAULT 0 CHECK (gaships >= 0),
|
||||
fighters INT NOT NULL DEFAULT 0 CHECK (fighters >= 0),
|
||||
cruisers INT NOT NULL DEFAULT 0 CHECK (cruisers >= 0),
|
||||
bcruisers INT NOT NULL DEFAULT 0 CHECK (bcruisers >= 0),
|
||||
attacking BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
can_move CHAR(1) NOT NULL DEFAULT 'Y' CHECK(can_move IN ('Y','H','B')),
|
||||
moving BIGINT REFERENCES moving_object (id) ON DELETE SET NULL,
|
||||
waiting BIGINT REFERENCES hs_wait (id) ON DELETE SET NULL,
|
||||
time_spent INT NOT NULL DEFAULT 0,
|
||||
sale SMALLINT,
|
||||
CHECK(gaships + fighters + cruisers + bcruisers > 0)
|
||||
);
|
||||
|
||||
CREATE INDEX fleet_owner ON fleet (owner);
|
||||
CREATE INDEX fleet_location ON fleet (location);
|
||||
CREATE INDEX fleet_moving ON fleet (moving);
|
||||
CREATE INDEX fleet_waiting ON fleet (waiting);
|
||||
|
||||
GRANT INSERT,SELECT,DELETE,UPDATE ON fleet TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON fleet_id_seq TO legacyworlds;
|
||||
|
101
sql/beta5/structure/04-sales.sql
Normal file
101
sql/beta5/structure/04-sales.sql
Normal file
|
@ -0,0 +1,101 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/04-sales.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- The various tables that store information associated
|
||||
-- with fleet and planet sales
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TABLE sale (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
player BIGINT NOT NULL REFERENCES player (id),
|
||||
started INT NOT NULL DEFAULT UNIX_TIMESTAMP(NOW()),
|
||||
expires INT,
|
||||
fleet BIGINT REFERENCES fleet (id),
|
||||
planet BIGINT REFERENCES planet (id),
|
||||
finalized INT,
|
||||
sold_to BIGINT REFERENCES player (id),
|
||||
CHECK(expires IS NULL OR expires > started),
|
||||
CHECK(fleet IS NOT NULL OR planet IS NOT NULL),
|
||||
CHECK(finalized IS NULL AND sold_to IS NULL OR finalized IS NOT NULL AND sold_to IS NOT NULL)
|
||||
);
|
||||
|
||||
CREATE INDEX sale_player ON sale (player);
|
||||
CREATE INDEX sale_fleet ON sale (fleet);
|
||||
CREATE INDEX sale_planet ON sale (planet);
|
||||
CREATE INDEX sale_sold_to ON sale (sold_to);
|
||||
|
||||
GRANT INSERT,SELECT,DELETE,UPDATE ON sale TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON sale_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE private_offer (
|
||||
offer BIGINT NOT NULL REFERENCES sale (id) ON DELETE CASCADE PRIMARY KEY,
|
||||
to_player BIGINT NOT NULL REFERENCES player (id),
|
||||
price INT NOT NULL DEFAULT 0 CHECK(price >= 0)
|
||||
);
|
||||
|
||||
CREATE INDEX p_offer_to ON private_offer (to_player);
|
||||
GRANT INSERT,SELECT,DELETE,UPDATE ON private_offer TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE public_offer (
|
||||
offer BIGINT NOT NULL REFERENCES sale (id) ON DELETE CASCADE PRIMARY KEY,
|
||||
price INT NOT NULL DEFAULT 0 CHECK(price > 0),
|
||||
auction BOOLEAN NOT NULL DEFAULT FALSE
|
||||
);
|
||||
GRANT INSERT,SELECT,DELETE,UPDATE ON public_offer TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE auction (
|
||||
offer BIGINT NOT NULL REFERENCES sale (id) ON DELETE CASCADE,
|
||||
player BIGINT NOT NULL REFERENCES player (id),
|
||||
moment INT NOT NULL DEFAULT UNIX_TIMESTAMP(NOW()),
|
||||
price INT NOT NULL CHECK(price > 0),
|
||||
PRIMARY KEY(offer, player, moment)
|
||||
);
|
||||
|
||||
CREATE INDEX auction_player ON auction (player);
|
||||
GRANT SELECT,INSERT,DELETE ON auction TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE sale_history (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
offer BIGINT REFERENCES sale (id) ON DELETE SET NULL,
|
||||
from_player BIGINT NOT NULL REFERENCES player (id),
|
||||
to_player BIGINT REFERENCES player (id),
|
||||
started INT NOT NULL DEFAULT UNIX_TIMESTAMP(NOW()),
|
||||
ended INT,
|
||||
mode SMALLINT NOT NULL,
|
||||
end_mode SMALLINT,
|
||||
price INT NOT NULL CHECK(price >= 0),
|
||||
sell_price INT CHECK(sell_price IS NULL OR sell_price >= 0),
|
||||
p_id BIGINT REFERENCES planet (id),
|
||||
p_name VARCHAR(15) NOT NULL,
|
||||
is_planet BOOLEAN NOT NULL,
|
||||
p_pop INT,
|
||||
p_turrets INT,
|
||||
p_factories INT,
|
||||
f_gaships INT NOT NULL DEFAULT 0,
|
||||
f_fighters INT NOT NULL DEFAULT 0,
|
||||
f_cruisers INT NOT NULL DEFAULT 0,
|
||||
f_bcruisers INT NOT NULL DEFAULT 0,
|
||||
CHECK(ended IS NULL OR ended > started)
|
||||
);
|
||||
|
||||
CREATE INDEX shist_offer ON sale_history (offer);
|
||||
CREATE INDEX shist_from_player ON sale_history (from_player);
|
||||
CREATE INDEX shist_to_player ON sale_history (to_player);
|
||||
CREATE INDEX shist_planet ON sale_history (p_id);
|
||||
|
||||
GRANT INSERT,UPDATE,SELECT,DELETE ON sale_history TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON sale_history_id_seq TO legacyworlds;
|
71
sql/beta5/structure/05-message-player.sql
Normal file
71
sql/beta5/structure/05-message-player.sql
Normal file
|
@ -0,0 +1,71 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/05-message-player.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Tables for the player-controlled messages
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
CREATE TABLE msg_std (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
sender BIGINT NOT NULL REFERENCES player (id),
|
||||
recipient BIGINT NOT NULL REFERENCES player (id),
|
||||
subject VARCHAR(64) NOT NULL,
|
||||
message text NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX msg_std_sender ON msg_std (sender);
|
||||
CREATE INDEX msg_std_recipient ON msg_std (recipient);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_std TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE msg_planet (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
planet BIGINT NOT NULL REFERENCES planet (id),
|
||||
pname VARCHAR(15) NOT NULL,
|
||||
sender BIGINT NOT NULL REFERENCES player (id),
|
||||
subject VARCHAR(64) NOT NULL,
|
||||
message text NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX msg_planet_sender ON msg_planet (sender);
|
||||
CREATE INDEX msg_planet_planet ON msg_planet (planet);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_planet TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE msg_alliance (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
sender BIGINT NOT NULL REFERENCES player (id),
|
||||
alliance INT REFERENCES alliance (id) ON DELETE SET NULL,
|
||||
tag VARCHAR(5) NOT NULL,
|
||||
subject VARCHAR(64) NOT NULL,
|
||||
message TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX msg_alliance_sender ON msg_alliance (sender);
|
||||
CREATE INDEX msg_alliance_alliance ON msg_alliance (alliance);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_alliance TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
CREATE TABLE msg_diplchan (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
sender BIGINT NOT NULL REFERENCES player (id),
|
||||
recipient BIGINT NOT NULL REFERENCES player (id),
|
||||
alliance INT REFERENCES alliance (id) ON DELETE SET NULL,
|
||||
tag VARCHAR(5) NOT NULL,
|
||||
subject VARCHAR(64) NOT NULL,
|
||||
message TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX msg_diplchan_sender ON msg_diplchan (sender);
|
||||
CREATE INDEX msg_diplchan_recipient ON msg_diplchan (recipient);
|
||||
CREATE INDEX msg_diplchan_alliance ON msg_diplchan (alliance);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_diplchan TO legacyworlds;
|
56
sql/beta5/structure/06-message-battle.sql
Normal file
56
sql/beta5/structure/06-message-battle.sql
Normal file
|
@ -0,0 +1,56 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/06-message-battle.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Table to store battle reports
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
CREATE TABLE msg_battle (
|
||||
id BIGINT NOT NULL REFERENCES message (id) ON DELETE CASCADE,
|
||||
planet_id BIGINT NOT NULL REFERENCES planet (id),
|
||||
planet VARCHAR(15) NOT NULL,
|
||||
o_gaships INT NOT NULL DEFAULT 0,
|
||||
o_fighters INT NOT NULL DEFAULT 0,
|
||||
o_cruisers INT NOT NULL DEFAULT 0,
|
||||
o_bcruisers INT NOT NULL DEFAULT 0,
|
||||
o_power INT NOT NULL DEFAULT 0,
|
||||
ol_gaships INT NOT NULL DEFAULT 0,
|
||||
ol_fighters INT NOT NULL DEFAULT 0,
|
||||
ol_cruisers INT NOT NULL DEFAULT 0,
|
||||
ol_bcruisers INT NOT NULL DEFAULT 0,
|
||||
ol_power INT NOT NULL DEFAULT 0,
|
||||
a_gaships INT NOT NULL DEFAULT 0,
|
||||
a_fighters INT NOT NULL DEFAULT 0,
|
||||
a_cruisers INT NOT NULL DEFAULT 0,
|
||||
a_bcruisers INT NOT NULL DEFAULT 0,
|
||||
a_power INT NOT NULL DEFAULT 0,
|
||||
al_gaships INT NOT NULL DEFAULT 0,
|
||||
al_fighters INT NOT NULL DEFAULT 0,
|
||||
al_cruisers INT NOT NULL DEFAULT 0,
|
||||
al_bcruisers INT NOT NULL DEFAULT 0,
|
||||
al_power INT NOT NULL DEFAULT 0,
|
||||
e_gaships INT NOT NULL DEFAULT 0,
|
||||
e_fighters INT NOT NULL DEFAULT 0,
|
||||
e_cruisers INT NOT NULL DEFAULT 0,
|
||||
e_bcruisers INT NOT NULL DEFAULT 0,
|
||||
e_power INT NOT NULL DEFAULT 0,
|
||||
el_gaships INT NOT NULL DEFAULT 0,
|
||||
el_fighters INT NOT NULL DEFAULT 0,
|
||||
el_cruisers INT NOT NULL DEFAULT 0,
|
||||
el_bcruisers INT NOT NULL DEFAULT 0,
|
||||
el_power INT NOT NULL DEFAULT 0,
|
||||
turrets INT NOT NULL DEFAULT 0,
|
||||
tpower INT NOT NULL DEFAULT 0,
|
||||
l_turrets INT NOT NULL DEFAULT 0,
|
||||
l_tpower INT NOT NULL DEFAULT 0,
|
||||
tmode SMALLINT NOT NULL DEFAULT 0,
|
||||
heroic_def INT NOT NULL CHECK(heroic_def >= -1 AND heroic_def <= 1)
|
||||
);
|
||||
CREATE INDEX msg_battle_planet ON msg_battle (planet_id);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_battle TO legacyworlds;
|
341
sql/beta5/structure/06-message-internal.sql
Normal file
341
sql/beta5/structure/06-message-internal.sql
Normal file
|
@ -0,0 +1,341 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/06-message-internal.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Tables for all types of internal messages except for
|
||||
-- battle reports
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Planets being abandoned
|
||||
--
|
||||
CREATE TABLE msg_abandon (
|
||||
id BIGINT NOT NULL REFERENCES message (id) ON DELETE CASCADE,
|
||||
p_id BIGINT NOT NULL REFERENCES planet (id),
|
||||
p_name VARCHAR(15) NOT NULL,
|
||||
PRIMARY KEY (id, p_id)
|
||||
);
|
||||
CREATE INDEX msg_abandon_planet ON msg_abandon (p_id);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_abandon TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Alliance internal messages
|
||||
--
|
||||
CREATE TABLE msg_alint (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
alliance INT REFERENCES alliance (id) ON DELETE SET NULL,
|
||||
tag VARCHAR(5) NOT NULL,
|
||||
player BIGINT REFERENCES player (id),
|
||||
msg_type SMALLINT NOT NULL CHECK(msg_type >= 0)
|
||||
);
|
||||
CREATE INDEX msg_alint_alliance ON msg_alint (alliance);
|
||||
CREATE INDEX msg_alint_player ON msg_alint (player);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_alint TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Bids on auction sales
|
||||
--
|
||||
CREATE TABLE msg_bid (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
offer BIGINT REFERENCES public_offer (offer) ON DELETE SET NULL,
|
||||
is_planet BOOLEAN NOT NULL,
|
||||
pname VARCHAR(15) NOT NULL,
|
||||
planet BIGINT NOT NULL REFERENCES planet (id),
|
||||
f_gas INT NOT NULL DEFAULT 0,
|
||||
f_fighters INT NOT NULL DEFAULT 0,
|
||||
f_cruisers INT NOT NULL DEFAULT 0,
|
||||
f_bcruisers INT NOT NULL DEFAULT 0,
|
||||
new_price INT NOT NULL DEFAULT 0,
|
||||
last_bidder BIGINT REFERENCES player (id)
|
||||
);
|
||||
CREATE INDEX msg_bid_offer ON msg_bid (offer);
|
||||
CREATE INDEX msg_bid_planet ON msg_bid (planet);
|
||||
CREATE INDEX msg_bid_last_bidder ON msg_bid (last_bidder);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_bid TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Cash donations
|
||||
--
|
||||
CREATE TABLE msg_cash (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
p_id BIGINT NOT NULL REFERENCES player (id),
|
||||
amount INT NOT NULL CHECK(amount > 0)
|
||||
);
|
||||
CREATE INDEX msg_cash_player ON msg_cash (p_id);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_cash TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Fleet movements
|
||||
--
|
||||
CREATE TABLE msg_flmove (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
p_id BIGINT NOT NULL REFERENCES planet (id),
|
||||
p_name VARCHAR(15) NOT NULL
|
||||
);
|
||||
CREATE INDEX msg_flmove_planet ON msg_flmove (p_id);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_flmove TO legacyworlds;
|
||||
|
||||
CREATE TABLE flmove_data (
|
||||
id BIGINT NOT NULL REFERENCES msg_flmove (id) ON DELETE CASCADE,
|
||||
f_name VARCHAR(64) NOT NULL,
|
||||
f_owner BIGINT NOT NULL REFERENCES player (id),
|
||||
f_gaships INT NOT NULL DEFAULT 0,
|
||||
f_fighters INT NOT NULL DEFAULT 0,
|
||||
f_cruisers INT NOT NULL DEFAULT 0,
|
||||
f_bcruisers INT NOT NULL DEFAULT 0,
|
||||
f_power INT NOT NULL,
|
||||
hostile BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
arrived BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
from_id BIGINT REFERENCES planet (id),
|
||||
from_name VARCHAR(15)
|
||||
);
|
||||
CREATE INDEX flmove_id ON flmove_data (id);
|
||||
CREATE INDEX flmove_owner ON flmove_data (f_owner);
|
||||
CREATE INDEX flmove_origin ON flmove_data (from_id);
|
||||
GRANT INSERT,DELETE,SELECT ON flmove_data TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Fleets that get switched to attack due to enemy lists
|
||||
--
|
||||
CREATE TABLE msg_flswitch (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
planet BIGINT NOT NULL REFERENCES planet (id),
|
||||
pname VARCHAR(15) NOT NULL,
|
||||
n_fleets INT NOT NULL CHECK(n_fleets > 0),
|
||||
fpower INT NOT NULL CHECK(fpower > 0)
|
||||
);
|
||||
CREATE INDEX msg_flswitch_planet ON msg_flswitch (planet);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_flswitch TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Hyperspace standby losses
|
||||
--
|
||||
CREATE TABLE msg_hsloss (
|
||||
id BIGINT NOT NULL REFERENCES message (id) ON DELETE CASCADE,
|
||||
p_id BIGINT NOT NULL REFERENCES planet (id),
|
||||
p_name VARCHAR(15) NOT NULL,
|
||||
f_name VARCHAR(64) NOT NULL,
|
||||
gaships INT NOT NULL DEFAULT 0,
|
||||
fighters INT NOT NULL DEFAULT 0,
|
||||
cruisers INT NOT NULL DEFAULT 0,
|
||||
bcruisers INT NOT NULL DEFAULT 0,
|
||||
power INT NOT NULL CHECK(power > 0)
|
||||
);
|
||||
CREATE INDEX msg_hsloss_idx ON msg_hsloss (id,p_id);
|
||||
CREATE INDEX msg_hsloss_planet ON msg_hsloss (p_id);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_hsloss TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Fleet losses due to insufficient income
|
||||
--
|
||||
CREATE TABLE msg_kfleet (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
gaships INT NOT NULL DEFAULT 0,
|
||||
fighters INT NOT NULL DEFAULT 0,
|
||||
cruisers INT NOT NULL DEFAULT 0,
|
||||
bcruisers INT NOT NULL DEFAULT 0
|
||||
);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_kfleet TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Planetary improvents losses due to insufficient income
|
||||
--
|
||||
CREATE TABLE msg_kimpr (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
turrets INT NOT NULL DEFAULT 0,
|
||||
factories INT NOT NULL DEFAULT 0
|
||||
);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_kimpr TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Players leaving the game
|
||||
--
|
||||
CREATE TABLE msg_leave (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
player BIGINT NOT NULL REFERENCES player (id),
|
||||
reason CHAR(4) NOT NULL DEFAULT 'QUIT' CHECK(reason IN ('QUIT', 'INAC', 'KICK')),
|
||||
tag VARCHAR(5),
|
||||
ally BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
sales_to INT NOT NULL DEFAULT 0,
|
||||
sales_from INT NOT NULL DEFAULT 0
|
||||
);
|
||||
CREATE INDEX msg_leave_player ON msg_leave (player);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_leave TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Planet owner changes
|
||||
--
|
||||
CREATE TABLE msg_ownerch (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
owner BIGINT NULL REFERENCES player (id),
|
||||
p_id BIGINT NOT NULL REFERENCES planet (id),
|
||||
p_name VARCHAR(15) NOT NULL,
|
||||
status CHAR(4) NOT NULL CHECK(status IN ('LOSE', 'TAKE', 'VIEW'))
|
||||
);
|
||||
CREATE INDEX msg_ownerch_owner ON msg_ownerch (owner);
|
||||
CREATE INDEX msg_ownerch_planet ON msg_ownerch (p_id);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_ownerch TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Planet sales cancelled due to owner changes
|
||||
--
|
||||
CREATE TABLE msg_plsc (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
seller BIGINT NOT NULL REFERENCES player (id),
|
||||
taker BIGINT NOT NULL REFERENCES player (id),
|
||||
p_id BIGINT NOT NULL REFERENCES planet (id),
|
||||
p_name VARCHAR(15) NOT NULL
|
||||
);
|
||||
CREATE INDEX msg_plsc_seller ON msg_plsc (seller);
|
||||
CREATE INDEX msg_plsc_taker ON msg_plsc (taker);
|
||||
CREATE INDEX msg_plsc_planet ON msg_plsc (p_id);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_plsc TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Planets being renamed
|
||||
--
|
||||
CREATE TABLE msg_rename (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
planet BIGINT NOT NULL REFERENCES planet (id),
|
||||
status CHAR(5) NOT NULL DEFAULT 'ORBIT' CHECK(status IN ('ORBIT','MOVE','PROBE')),
|
||||
old_name VARCHAR(15) NOT NULL,
|
||||
new_name VARCHAR(15) NOT NULL
|
||||
);
|
||||
CREATE INDEX msg_rename_planet ON msg_rename (planet);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_rename TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Research diplomacy messages
|
||||
--
|
||||
CREATE TABLE msg_resdipl (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
offer BIGINT NOT NULL REFERENCES research_assistance (id),
|
||||
msg_id SMALLINT NOT NULL CHECK(msg_id >= 0)
|
||||
);
|
||||
CREATE INDEX msg_resdipl_offer ON msg_resdipl (offer);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_resdipl TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Damage to infrastructure because of revolts
|
||||
--
|
||||
CREATE TABLE msg_revdmg (
|
||||
id BIGINT NOT NULL REFERENCES message (id) ON DELETE CASCADE,
|
||||
planet BIGINT NOT NULL REFERENCES planet (id),
|
||||
pname VARCHAR(15) NOT NULL,
|
||||
ifact INT NOT NULL DEFAULT 0,
|
||||
mfact INT NOT NULL DEFAULT 0,
|
||||
turrets INT NOT NULL DEFAULT 0,
|
||||
PRIMARY KEY (id, planet)
|
||||
);
|
||||
CREATE INDEX msg_revdmg_planet ON msg_revdmg (planet);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_revdmg TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Beginning and end of revolts
|
||||
--
|
||||
CREATE TABLE msg_revolt (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
planet BIGINT NOT NULL REFERENCES planet (id),
|
||||
pname VARCHAR(15) NOT NULL,
|
||||
started BOOLEAN NOT NULL
|
||||
);
|
||||
CREATE INDEX msg_revolt_planet ON msg_revolt (planet);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_revolt TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Sales
|
||||
--
|
||||
CREATE TABLE msg_sale (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
p_id BIGINT REFERENCES planet (id),
|
||||
p_name VARCHAR(15),
|
||||
f_name VARCHAR(64),
|
||||
f_power INT,
|
||||
pl_id BIGINT NOT NULL REFERENCES player (id),
|
||||
pl_name VARCHAR(15) NOT NULL,
|
||||
is_sale BOOLEAN NOT NULL DEFAULT FALSE
|
||||
);
|
||||
CREATE INDEX msg_sale_planet ON msg_sale (p_id);
|
||||
CREATE INDEX msg_sale_player ON msg_sale (pl_id);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_sale TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Warnings for incorrect planet names
|
||||
--
|
||||
CREATE TABLE msg_warnname (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
moderator BIGINT NOT NULL REFERENCES player (id),
|
||||
planet BIGINT NOT NULL REFERENCES planet (id),
|
||||
p_name VARCHAR(15) NOT NULL,
|
||||
event CHAR(5) NOT NULL DEFAULT 'WARN' CHECK(event IN ('WARN', 'NEUT', 'ANEUT'))
|
||||
);
|
||||
CREATE INDEX msg_warnname_moderator ON msg_warnname (moderator);
|
||||
CREATE INDEX msg_warnname_planet ON msg_warnname (planet);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_warnname TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Planets that get blown up by the WHSN tech
|
||||
--
|
||||
CREATE TABLE msg_whsn (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
p_id BIGINT NOT NULL REFERENCES planet (id),
|
||||
p_name VARCHAR(15) NOT NULL,
|
||||
was_owner BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
f_power INT NOT NULL DEFAULT 0,
|
||||
e_power INT NOT NULL DEFAULT 0
|
||||
);
|
||||
CREATE INDEX msg_whsn_planet ON msg_whsn (p_id);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_whsn TO legacyworlds;
|
||||
|
||||
CREATE TABLE whsn_fleet (
|
||||
id BIGINT NOT NULL REFERENCES msg_whsn (id) ON DELETE CASCADE,
|
||||
name VARCHAR(64) NOT NULL,
|
||||
gaships INT NOT NULL DEFAULT 0,
|
||||
fighters INT NOT NULL DEFAULT 0,
|
||||
cruisers INT NOT NULL DEFAULT 0,
|
||||
bcruisers INT NOT NULL DEFAULT 0,
|
||||
power INT NOT NULL CHECK(power > 0)
|
||||
);
|
||||
CREATE INDEX whsn_fleet_msg ON whsn_fleet (id);
|
||||
GRANT INSERT,DELETE,SELECT ON whsn_fleet TO legacyworlds;
|
58
sql/beta5/structure/07-beacons.sql
Normal file
58
sql/beta5/structure/07-beacons.sql
Normal file
|
@ -0,0 +1,58 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/07-beacons.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Tables that handle detection of fleets in HSSB by
|
||||
-- beacons.
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Detection status
|
||||
--
|
||||
-- Fleets should be listed in this table when they get
|
||||
-- detected.
|
||||
--
|
||||
|
||||
CREATE TABLE beacon_detection (
|
||||
planet BIGINT NOT NULL REFERENCES planet (id),
|
||||
fleet BIGINT NOT NULL REFERENCES fleet (id) ON DELETE CASCADE,
|
||||
i_level INT NOT NULL CHECK( i_level >= 0 AND i_level <= 4 ),
|
||||
fl_size INT,
|
||||
fl_owner BIGINT REFERENCES player (id) ON DELETE CASCADE,
|
||||
PRIMARY KEY (planet, fleet),
|
||||
|
||||
CHECK( i_level = 0 AND fl_size IS NULL OR i_level > 0 AND fl_size IS NOT NULL ),
|
||||
CHECK( i_level < 4 AND fl_owner IS NULL OR i_level = 4 AND fl_owner IS NOT NULL )
|
||||
);
|
||||
|
||||
CREATE INDEX beacon_detection_fleet ON beacon_detection (fleet);
|
||||
CREATE INDEX beacon_detection_owner ON beacon_detection (fl_owner);
|
||||
GRANT SELECT,INSERT,DELETE ON beacon_detection TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Message table
|
||||
--
|
||||
|
||||
CREATE TABLE msg_detect (
|
||||
id BIGINT PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
planet BIGINT REFERENCES planet (id) ON DELETE CASCADE,
|
||||
p_name VARCHAR(15) NOT NULL,
|
||||
is_owner BOOLEAN NOT NULL,
|
||||
i_level INT NOT NULL CHECK( i_level >= 0 AND i_level <= 4 ),
|
||||
fl_size INT,
|
||||
flo_id BIGINT REFERENCES player (id) ON DELETE SET NULL,
|
||||
flo_name VARCHAR(15),
|
||||
|
||||
CHECK( is_owner OR NOT is_owner AND (i_level = 0 AND fl_size IS NULL OR i_level > 0 AND fl_size IS NOT NULL) ),
|
||||
CHECK( is_owner OR NOT is_owner AND (i_level < 4 AND flo_name IS NULL OR i_level = 4 AND flo_name IS NOT NULL) )
|
||||
);
|
||||
|
||||
CREATE INDEX msg_detect_planet ON msg_detect (planet);
|
||||
CREATE INDEX msg_detect_owner ON msg_detect (flo_id);
|
||||
GRANT SELECT,INSERT,DELETE ON msg_detect TO legacyworlds;
|
41
sql/beta5/structure/07-message-admin.sql
Normal file
41
sql/beta5/structure/07-message-admin.sql
Normal file
|
@ -0,0 +1,41 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/07-message-admin.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Tables required to send "administrative spam" to all
|
||||
-- players.
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Contents table
|
||||
--
|
||||
|
||||
CREATE TABLE admin_spam (
|
||||
id SERIAL PRIMARY KEY,
|
||||
sent_by BIGINT NOT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
subject VARCHAR(64) NOT NULL,
|
||||
contents TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX admin_spam_sender ON admin_spam (sent_by);
|
||||
|
||||
GRANT SELECT,INSERT ON admin_spam TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON admin_spam_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Message table
|
||||
--
|
||||
|
||||
CREATE TABLE msg_admin (
|
||||
id BIGINT PRIMARY KEY REFERENCES message(id) ON DELETE CASCADE,
|
||||
spam INT NOT NULL REFERENCES admin_spam (id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE INDEX msg_admin_spam ON msg_admin (spam);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_admin TO legacyworlds;
|
99
sql/beta5/structure/10-ctf-tables.sql
Normal file
99
sql/beta5/structure/10-ctf-tables.sql
Normal file
|
@ -0,0 +1,99 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/10-ctf-tables.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Tables specific to CTF games
|
||||
--
|
||||
-- Copyright(C) 2004-2008, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Target status
|
||||
--
|
||||
-- Targets are always listed in this table, and the status
|
||||
-- of the targets is set according to who holds the system.
|
||||
--
|
||||
|
||||
CREATE TABLE ctf_target (
|
||||
system INT PRIMARY KEY REFERENCES system (id),
|
||||
held_by INT REFERENCES alliance (id),
|
||||
held_since INT,
|
||||
grace_expires INT,
|
||||
|
||||
CHECK( (held_by IS NULL AND held_since IS NULL)
|
||||
OR (held_by IS NOT NULL AND held_since IS NOT NULL) ),
|
||||
|
||||
CHECK( (held_by IS NULL AND grace_expires IS NULL) OR held_by IS NOT NULL )
|
||||
);
|
||||
|
||||
CREATE INDEX ctf_target_alliance ON ctf_target (held_by);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE ON ctf_target TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Allocated system status
|
||||
--
|
||||
-- This is used in order to clear players out of other
|
||||
-- teams' zones and to know where each player was spawned.
|
||||
--
|
||||
|
||||
CREATE TABLE ctf_alloc (
|
||||
system INT PRIMARY KEY REFERENCES system (id),
|
||||
alliance INT NOT NULL CHECK( alliance > 0 AND alliance < 9 ),
|
||||
spawn_point BOOLEAN NOT NULL,
|
||||
player BIGINT REFERENCES player (id),
|
||||
|
||||
CHECK( spawn_point OR (NOT spawn_point AND player IS NULL) )
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE ON ctf_alloc TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Team points
|
||||
--
|
||||
-- This table stores the points for each team
|
||||
--
|
||||
|
||||
CREATE TABLE ctf_points (
|
||||
team INT NOT NULL PRIMARY KEY REFERENCES alliance(id),
|
||||
points INT NOT NULL DEFAULT 0 CHECK (points >= 0 AND points <= 100)
|
||||
);
|
||||
GRANT SELECT,INSERT,UPDATE ON ctf_points TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Game messages
|
||||
--
|
||||
-- The message type is one of the following:
|
||||
-- 0 => Player joined the game, inform him [team]
|
||||
-- 1 => Player joined a team, inform the rest of the team [team]
|
||||
-- 2 => A player's team is now holding all the targets [team,time_stamp]
|
||||
-- 3 => Another team is now holding all the targets [team,time_stamp]
|
||||
-- 4 => A player's team is no longer holding all the targets, but there is a grace period [team,time_stamp]
|
||||
-- 5 => A player's team is no longer holding all the targets, and there is no grace period [team]
|
||||
-- 6 => A player's team is no longer holding all the targets, and the grace period has expired [team]
|
||||
-- 7 => Another team is no longer holding all the targets, but there is a grace period [team,time_stamp]
|
||||
-- 8 => Another team is no longer holding all the targets, and there is no grace period [team]
|
||||
-- 9 => Another team is no longer holding all the targets, and the grace period has expired [team]
|
||||
-- 10 => A player's team is still holding the targets after half the required time [team,time_stamp]
|
||||
-- 11 => Another team is still holding the targets after half the required time [team,time_stamp]
|
||||
-- 12 => A player's team has held the targets long enough and the game has been reset [team]
|
||||
-- 13 => Another team has held the targets long enough and the game has been reset [team]
|
||||
-- 14 => A player's team has won the match [team]
|
||||
-- 15 => A player's team has lost the match [team]
|
||||
|
||||
CREATE TABLE msg_ctf (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
msg_type INT NOT NULL CHECK(msg_type >= 0 AND msg_type < 16),
|
||||
team INT NOT NULL REFERENCES alliance (id),
|
||||
time_stamp INT
|
||||
);
|
||||
|
||||
CREATE INDEX msg_ctf_team ON msg_ctf (team);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON msg_ctf TO legacyworlds;
|
89
sql/beta5/structure/10-prot-tables.sql
Normal file
89
sql/beta5/structure/10-prot-tables.sql
Normal file
|
@ -0,0 +1,89 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/10-prot-tables.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Tables to support protection
|
||||
--
|
||||
-- Copyright(C) 2004-2008, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Enemies of the Peacekeepers
|
||||
--
|
||||
CREATE TABLE pk_enemy (
|
||||
player BIGINT NOT NULL PRIMARY KEY REFERENCES player (id) ON DELETE CASCADE,
|
||||
until INT NOT NULL
|
||||
);
|
||||
CREATE INDEX pk_enemy_until ON pk_enemy (until);
|
||||
GRANT SELECT,INSERT,DELETE,UPDATE ON pk_enemy TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Offenses against protected systems
|
||||
--
|
||||
CREATE TABLE pk_offenses (
|
||||
player BIGINT NOT NULL PRIMARY KEY REFERENCES player (id) ON DELETE CASCADE,
|
||||
nb_offenses INT NOT NULL
|
||||
);
|
||||
CREATE INDEX pk_offenses_nb ON pk_offenses (nb_offenses);
|
||||
GRANT SELECT,INSERT,DELETE,UPDATE ON pk_offenses TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- System status
|
||||
--
|
||||
-- Status is one of:
|
||||
-- A -> Allied player
|
||||
-- W -> Warning sent
|
||||
-- O -> Player is on the offensive
|
||||
-- E -> Player has been declared an enemy
|
||||
--
|
||||
CREATE TABLE pk_sys_status (
|
||||
system INT NOT NULL REFERENCES system (id),
|
||||
player BIGINT NOT NULL REFERENCES player (id) ON DELETE CASCADE,
|
||||
status CHAR(1) NOT NULL CHECK(status IN ('A', 'W', 'O', 'E')),
|
||||
switch_at INT,
|
||||
PRIMARY KEY (system, player)
|
||||
);
|
||||
CREATE INDEX pk_sys_status_system ON pk_sys_status (system);
|
||||
CREATE INDEX pk_sys_status_player ON pk_sys_status (player);
|
||||
CREATE INDEX pk_sys_status_status ON pk_sys_status (status);
|
||||
CREATE INDEX pk_sys_status_switch_at ON pk_sys_status (switch_at);
|
||||
GRANT SELECT,INSERT,DELETE,UPDATE ON pk_sys_status TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- End of protection messages
|
||||
--
|
||||
CREATE TABLE msg_endprotection (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
end_type CHAR(3) NOT NULL CHECK (end_type IN ('BRK', 'ACT', 'EXP'))
|
||||
);
|
||||
GRANT INSERT,DELETE,SELECT ON msg_endprotection TO legacyworlds;
|
||||
|
||||
--
|
||||
-- Warnings from the Peacekeepers
|
||||
--
|
||||
-- msg_type is one of:
|
||||
-- 'W' -> warning, player must leave the planets
|
||||
-- 'D' -> "you will be destroyed"
|
||||
-- 'E' -> "you have been declared an enemy"
|
||||
--
|
||||
CREATE TABLE msg_pkwarning (
|
||||
id BIGINT NOT NULL PRIMARY KEY REFERENCES message (id) ON DELETE CASCADE,
|
||||
msg_type CHAR(1) NOT NULL CHECK(msg_type IN ('W', 'D', 'E')),
|
||||
delay INT
|
||||
);
|
||||
GRANT SELECT,INSERT,DELETE ON msg_pkwarning TO legacyworlds;
|
||||
|
||||
CREATE TABLE pkwarning_planet (
|
||||
id BIGINT NOT NULL REFERENCES msg_pkwarning (id) ON DELETE CASCADE,
|
||||
planet BIGINT NOT NULL REFERENCES planet (id),
|
||||
p_name VARCHAR(15) NOT NULL,
|
||||
PRIMARY KEY (id, planet)
|
||||
);
|
||||
CREATE INDEX pkwarning_planet_id ON pkwarning_planet (planet);
|
||||
GRANT SELECT,INSERT,DELETE ON pkwarning_planet TO legacyworlds;
|
15
sql/beta5/structure/99-player-fk.sql
Normal file
15
sql/beta5/structure/99-player-fk.sql
Normal file
|
@ -0,0 +1,15 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/99-player-fk.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Foreign keys on the player table
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
ALTER TABLE player ADD FOREIGN KEY (alliance) REFERENCES alliance (id) ON DELETE SET NULL;
|
||||
ALTER TABLE player ADD FOREIGN KEY (a_grade) REFERENCES alliance_grade (id) ON DELETE SET NULL;
|
||||
ALTER TABLE player ADD FOREIGN KEY (a_vote) REFERENCES alliance_candidate (id) ON DELETE SET NULL;
|
||||
ALTER TABLE player ADD FOREIGN KEY (first_planet) REFERENCES planet (id);
|
15
sql/beta5/structure/finalise.sql
Normal file
15
sql/beta5/structure/finalise.sql
Normal file
|
@ -0,0 +1,15 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/finalise.sql
|
||||
--
|
||||
-- Finalise a Beta 5 game database by revoking extra
|
||||
-- privileges from the user role and dropping helper
|
||||
-- functions
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
-- Revoke user privileges
|
||||
REVOKE INSERT ON gdata FROM legacyworlds;
|
||||
|
Loading…
Add table
Add a link
Reference in a new issue