Added full source code
This commit is contained in:
commit
33f8586698
1377 changed files with 123808 additions and 0 deletions
sql
00-init.sql01-inheritance.sql10-main.sql11-main-enums.sql12-main-tables.sql13-main-donations.sql13-main-forums.sql13-main-links.sql13-main-manual.sql13-main-proxy.sql18-main-functions.sql19-main-values.sql20-credits.sql25-ctf-maps.sql25-death-of-rats.sql25-predefined-alliances.sql30-beta5.sql50-beta6-planet-pictures.sqlINSTALL.sql
beta5
00-beta5.sql10-beta5-b5.sql11-beta5-b5m0.sqlbeta5-ctf.sqlbeta5-match.sqlbeta5-round.sql
data
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
70
sql/00-init.sql
Normal file
70
sql/00-init.sql
Normal file
|
@ -0,0 +1,70 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 00-init.sql
|
||||
--
|
||||
-- Initialises the various roles and the database itself
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
-- Connect to the main system database
|
||||
\c postgres postgres
|
||||
SET search_path=public;
|
||||
|
||||
-- Create the LW users
|
||||
CREATE ROLE legacyworlds WITH LOGIN ENCRYPTED PASSWORD 'main user password';
|
||||
CREATE ROLE legacyworlds_admin WITH LOGIN ENCRYPTED PASSWORD 'administration user password' CONNECTION LIMIT 2;
|
||||
|
||||
-- Create the database
|
||||
CREATE DATABASE legacyworlds WITH OWNER=legacyworlds_admin ENCODING='UTF8';
|
||||
|
||||
|
||||
|
||||
-- Connect to the LW database with the PostgreSQL admin user
|
||||
\c legacyworlds postgres
|
||||
|
||||
-- Register PL/PgSQL's handler function
|
||||
CREATE FUNCTION plpgsql_call_handler() RETURNS language_handler AS
|
||||
'$libdir/plpgsql' LANGUAGE C;
|
||||
|
||||
-- Register PL/PgSQL's validator function
|
||||
CREATE FUNCTION plpgsql_validator(oid) RETURNS void AS
|
||||
'$libdir/plpgsql' LANGUAGE C;
|
||||
|
||||
-- Register PL/PgSQL
|
||||
CREATE TRUSTED PROCEDURAL LANGUAGE plpgsql
|
||||
HANDLER plpgsql_call_handler
|
||||
VALIDATOR plpgsql_validator;
|
||||
|
||||
|
||||
|
||||
-- Connect to the LW database with the LW admin user
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
|
||||
--
|
||||
-- The following function returns the last inserted identifier for some table.
|
||||
--
|
||||
CREATE OR REPLACE FUNCTION last_inserted(tbl NAME) RETURNS BIGINT AS $$
|
||||
DECLARE
|
||||
i BIGINT;
|
||||
BEGIN
|
||||
SELECT INTO i currval(tbl || '_id_seq');
|
||||
RETURN i;
|
||||
EXCEPTION
|
||||
WHEN undefined_table OR object_not_in_prerequisite_state THEN
|
||||
RETURN NULL;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
--
|
||||
-- UNIX_TIMESPAMP() function for MySQL compatibility
|
||||
--
|
||||
CREATE OR REPLACE FUNCTION unix_timestamp(t TIMESTAMP WITH TIME ZONE) RETURNS INT AS $$
|
||||
SELECT CAST(EXTRACT(EPOCH FROM $1) AS INT);
|
||||
$$ LANGUAGE SQL;
|
||||
CREATE OR REPLACE FUNCTION unix_timestamp(t TIMESTAMP WITHOUT TIME ZONE) RETURNS INT AS $$
|
||||
SELECT CAST(EXTRACT(EPOCH FROM $1) AS INT);
|
||||
$$ LANGUAGE SQL;
|
1373
sql/01-inheritance.sql
Normal file
1373
sql/01-inheritance.sql
Normal file
File diff suppressed because it is too large
Load diff
19
sql/10-main.sql
Normal file
19
sql/10-main.sql
Normal file
|
@ -0,0 +1,19 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 10-main.sql
|
||||
--
|
||||
-- Initialises the main schema
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- Connect to the database
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
-- Create the main schema
|
||||
CREATE SCHEMA main;
|
||||
GRANT USAGE ON SCHEMA main TO legacyworlds;
|
||||
|
71
sql/11-main-enums.sql
Normal file
71
sql/11-main-enums.sql
Normal file
|
@ -0,0 +1,71 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 11-main-enums.sql
|
||||
--
|
||||
-- Initialises the tables to be used as enumerations for
|
||||
-- the main schema
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- Connect to the database
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
|
||||
--
|
||||
-- Create the account status table
|
||||
--
|
||||
|
||||
CREATE TABLE main.acnt_status (
|
||||
txt VARCHAR(6) PRIMARY KEY
|
||||
);
|
||||
GRANT SELECT ON TABLE main.acnt_status TO legacyworlds;
|
||||
|
||||
-- Fill the account status table
|
||||
COPY main.acnt_status FROM STDIN;
|
||||
NEW
|
||||
STD
|
||||
KICKED
|
||||
QUIT
|
||||
INAC
|
||||
VAC
|
||||
\.
|
||||
|
||||
|
||||
--
|
||||
-- Create the account log entry types list
|
||||
--
|
||||
|
||||
CREATE TABLE main.acnt_log_entry_type (
|
||||
txt VARCHAR(6) PRIMARY KEY
|
||||
);
|
||||
GRANT SELECT ON TABLE main.acnt_log_entry_type TO legacyworlds;
|
||||
|
||||
-- Fill the account log entry type table
|
||||
COPY main.acnt_log_entry_type FROM STDIN;
|
||||
IN
|
||||
OUT
|
||||
CREATE
|
||||
CONF
|
||||
QUIT
|
||||
VSTART
|
||||
VEND
|
||||
\.
|
||||
|
||||
|
||||
--
|
||||
-- Create the supported language list
|
||||
--
|
||||
|
||||
CREATE TABLE main.lang (
|
||||
txt VARCHAR(4) PRIMARY KEY
|
||||
);
|
||||
GRANT SELECT ON TABLE main.lang TO legacyworlds;
|
||||
|
||||
-- Fill the supported language table
|
||||
COPY main.lang FROM STDIN;
|
||||
en
|
||||
\.
|
223
sql/12-main-tables.sql
Normal file
223
sql/12-main-tables.sql
Normal file
|
@ -0,0 +1,223 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 12-main-tables.sql
|
||||
--
|
||||
-- Initialises the part of the database that contains
|
||||
-- the user accounts, logs ...
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- Connect to the database
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Create the account table
|
||||
--
|
||||
|
||||
CREATE TABLE main.account (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
name VARCHAR(15) NOT NULL UNIQUE,
|
||||
email VARCHAR(128) NOT NULL UNIQUE,
|
||||
password VARCHAR(64) NOT NULL,
|
||||
status VARCHAR(6) NOT NULL DEFAULT 'NEW' REFERENCES main.acnt_status (txt),
|
||||
conf_code VARCHAR(16) NULL,
|
||||
reason TEXT NULL,
|
||||
vac_credits INT NOT NULL DEFAULT 30 CHECK(vac_credits BETWEEN 0 AND 240),
|
||||
vac_start INT NULL CHECK(vac_start IS NULL OR (vac_start IS NOT NULL AND vac_credits > 0)),
|
||||
quit_ts INT NULL CHECK(quit_ts IS NULL OR quit_ts > 0),
|
||||
last_login INT NULL CHECK(last_login IS NULL OR last_login > 0),
|
||||
last_logout INT NULL CHECK(last_logout IS NULL OR last_logout > 0),
|
||||
pw_conf VARCHAR(16) NULL,
|
||||
admin BOOLEAN NOT NULL DEFAULT FALSE
|
||||
);
|
||||
|
||||
CREATE INDEX account_status ON main.account(status);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON TABLE main.account TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON main.account_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- The following table stores queued game registrations.
|
||||
--
|
||||
|
||||
CREATE TABLE main.reg_queue (
|
||||
account BIGINT NOT NULL PRIMARY KEY REFERENCES main.account (id)
|
||||
ON DELETE CASCADE,
|
||||
game VARCHAR(16) NOT NULL
|
||||
);
|
||||
GRANT SELECT,INSERT,DELETE ON main.reg_queue TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Create the table that stores kick requests
|
||||
--
|
||||
|
||||
CREATE TABLE main.adm_kick (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
to_kick BIGINT NOT NULL REFERENCES main.account (id),
|
||||
requested_by BIGINT NOT NULL REFERENCES main.account (id),
|
||||
requested_at INT NOT NULL DEFAULT INT4(EXTRACT(EPOCH FROM NOW())),
|
||||
reason TEXT NOT NULL,
|
||||
status CHAR(1) NOT NULL CHECK(status IN ('P','Y','N')),
|
||||
examined_by BIGINT REFERENCES main.account (id)
|
||||
);
|
||||
|
||||
CREATE INDEX adm_kick_to_kick ON main.adm_kick (to_kick);
|
||||
CREATE INDEX adm_kick_req_by ON main.adm_kick (requested_by);
|
||||
CREATE INDEX adm_kick_exam_by ON main.adm_kick (examined_by);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON TABLE main.adm_kick TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON main.adm_kick_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Create the table to handle tracking cookies
|
||||
--
|
||||
|
||||
CREATE TABLE main.web_tracking (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
cookie VARCHAR(32) NOT NULL UNIQUE,
|
||||
created INT NOT NULL DEFAULT INT4(EXTRACT(EPOCH FROM NOW())),
|
||||
last_used INT NOT NULL DEFAULT INT4(EXTRACT(EPOCH FROM NOW())),
|
||||
ip_addr VARCHAR(15) NOT NULL,
|
||||
browser VARCHAR(255) NOT NULL,
|
||||
stored_data TEXT NOT NULL DEFAULT 'a:0:{}'
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON TABLE main.web_tracking TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON main.web_tracking_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Create the session storage table
|
||||
--
|
||||
|
||||
CREATE TABLE main.web_session (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
cookie VARCHAR(32) NOT NULL UNIQUE,
|
||||
created INT NOT NULL DEFAULT INT4(EXTRACT(EPOCH FROM NOW())),
|
||||
last_used INT NOT NULL DEFAULT INT4(EXTRACT(EPOCH FROM NOW())),
|
||||
ip_addr VARCHAR(15) NOT NULL,
|
||||
account BIGINT REFERENCES main.account(id),
|
||||
stored_data TEXT NOT NULL DEFAULT 'a:0:{}',
|
||||
tracking BIGINT NOT NULL REFERENCES main.web_tracking(id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
CREATE INDEX web_session_tracking ON main.web_session (tracking);
|
||||
CREATE INDEX web_session_account ON main.web_session (account);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON TABLE main.web_session TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON main.web_session_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Create the account log table
|
||||
--
|
||||
CREATE TABLE main.account_log (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
account BIGINT NOT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
tracking BIGINT NULL REFERENCES main.web_tracking (id) ON DELETE SET NULL,
|
||||
ip_addr VARCHAR(18) NOT NULL DEFAULT 'AUTO',
|
||||
action VARCHAR(6) NOT NULL REFERENCES main.acnt_log_entry_type (txt),
|
||||
t INT NOT NULL DEFAULT INT4(EXTRACT(EPOCH FROM NOW()))
|
||||
);
|
||||
|
||||
CREATE INDEX acnt_log_account ON main.account_log (account);
|
||||
CREATE INDEX acnt_log_trk ON main.account_log (tracking);
|
||||
CREATE INDEX acnt_log_act ON main.account_log (action);
|
||||
|
||||
GRANT SELECT,INSERT,DELETE ON TABLE main.account_log TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON main.account_log_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Create the table that stores cache references
|
||||
--
|
||||
|
||||
CREATE TABLE main.web_cache (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
rtype VARCHAR(5) NOT NULL,
|
||||
md5 VARCHAR(32) NOT NULL,
|
||||
last_used BIGINT NOT NULL DEFAULT INT4(EXTRACT(EPOCH FROM NOW())),
|
||||
UNIQUE (rtype, md5)
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON TABLE main.web_cache TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON main.web_cache_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Tables that will store rankings definitions, texts, and
|
||||
-- game relations
|
||||
--
|
||||
|
||||
-- Definitions
|
||||
CREATE TABLE main.ranking_def (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
version VARCHAR(16) NOT NULL,
|
||||
name VARCHAR(16) NOT NULL,
|
||||
more BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
UNIQUE (version, name)
|
||||
);
|
||||
|
||||
GRANT SELECT ON TABLE main.ranking_def TO legacyworlds;
|
||||
|
||||
-- Descriptions
|
||||
CREATE TABLE main.ranking_text (
|
||||
ranking BIGINT NOT NULL REFERENCES main.ranking_def (id),
|
||||
lang VARCHAR(4) NOT NULL REFERENCES main.lang (txt),
|
||||
name VARCHAR(32) NOT NULL,
|
||||
description text NOT NULL,
|
||||
PRIMARY KEY (ranking, lang)
|
||||
);
|
||||
|
||||
CREATE INDEX rk_txt_lang ON main.ranking_text (lang);
|
||||
GRANT SELECT ON TABLE main.ranking_text TO legacyworlds;
|
||||
|
||||
|
||||
-- Games
|
||||
CREATE TABLE main.ranking_game (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
ranking BIGINT NOT NULL REFERENCES main.ranking_def (id),
|
||||
game VARCHAR(16) NOT NULL,
|
||||
UNIQUE (ranking, game)
|
||||
);
|
||||
|
||||
GRANT SELECT ON TABLE main.ranking_game TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Table that will store the rankings themselves
|
||||
--
|
||||
CREATE TABLE main.ranking (
|
||||
r_type BIGINT NOT NULL REFERENCES main.ranking_game (id) ON DELETE CASCADE,
|
||||
id VARCHAR(32) NOT NULL,
|
||||
additional TEXT,
|
||||
points BIGINT NOT NULL DEFAULT 0,
|
||||
ranking BIGINT NOT NULL,
|
||||
PRIMARY KEY (r_type, id)
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON TABLE main.ranking TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Table for user preferences
|
||||
--
|
||||
CREATE TABLE main.user_preferences (
|
||||
id VARCHAR(32) NOT NULL,
|
||||
version VARCHAR(16) NOT NULL,
|
||||
account BIGINT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
value VARCHAR(255) NOT NULL,
|
||||
UNIQUE (id, version, account)
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON TABLE main.user_preferences TO legacyworlds;
|
70
sql/13-main-donations.sql
Normal file
70
sql/13-main-donations.sql
Normal file
|
@ -0,0 +1,70 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 13-main-donations.sql
|
||||
--
|
||||
-- Initialises the part of the database that contains
|
||||
-- data related to PayPal donations
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- Connect to the database
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Create the ticket table
|
||||
--
|
||||
CREATE TABLE main.pp_ticket (
|
||||
md5_id VARCHAR(64) NOT NULL PRIMARY KEY,
|
||||
account BIGINT NOT NULL REFERENCES main.account (id),
|
||||
created INT NOT NULL DEFAULT UNIX_TIMESTAMP(NOW())
|
||||
);
|
||||
|
||||
CREATE INDEX pp_tick_acnt ON main.pp_ticket(account);
|
||||
GRANT SELECT,INSERT,DELETE ON TABLE main.pp_ticket TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Create the donations history table
|
||||
--
|
||||
CREATE TABLE main.pp_history (
|
||||
account BIGINT NOT NULL REFERENCES main.account (id),
|
||||
donated INT NOT NULL DEFAULT UNIX_TIMESTAMP(NOW()),
|
||||
amount FLOAT NOT NULL,
|
||||
PRIMARY KEY (account, donated)
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT ON TABLE main.pp_history TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Create the Paypal IPN log table
|
||||
--
|
||||
CREATE TABLE main.pp_ipn (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
received INT NOT NULL DEFAULT UNIX_TIMESTAMP(NOW()),
|
||||
receiver_email VARCHAR(127),
|
||||
item_number VARCHAR(127),
|
||||
payment_status VARCHAR(20),
|
||||
pending_reason VARCHAR(10),
|
||||
payment_date VARCHAR(20),
|
||||
mc_gross VARCHAR(20),
|
||||
mc_fee VARCHAR(20),
|
||||
tax VARCHAR(20),
|
||||
mc_currency VARCHAR(3),
|
||||
txn_id VARCHAR(20),
|
||||
txn_type VARCHAR(10),
|
||||
payer_email VARCHAR(127),
|
||||
payer_status VARCHAR(10),
|
||||
payment_type VARCHAR(10),
|
||||
verify_sign VARCHAR(10),
|
||||
referrer_id VARCHAR(10)
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT ON TABLE main.pp_ipn TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON main.pp_ipn_id_seq TO legacyworlds;
|
149
sql/13-main-forums.sql
Normal file
149
sql/13-main-forums.sql
Normal file
|
@ -0,0 +1,149 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 13-main-forums.sql
|
||||
--
|
||||
-- Tables for the forums
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- Connect to the database
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Forum categories
|
||||
--
|
||||
CREATE TABLE main.f_category (
|
||||
id SERIAL NOT NULL PRIMARY KEY,
|
||||
corder INT NOT NULL UNIQUE CHECK(corder >= 0),
|
||||
title VARCHAR(64) NOT NULL UNIQUE,
|
||||
description TEXT
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT ON TABLE main.f_category TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON main.f_category_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Forums
|
||||
--
|
||||
CREATE TABLE main.f_forum (
|
||||
id SERIAL NOT NULL PRIMARY KEY,
|
||||
category INT NOT NULL REFERENCES main.f_category (id) ON DELETE CASCADE,
|
||||
forder INT NOT NULL DEFAULT 0 CHECK(forder >= 0),
|
||||
title VARCHAR(64) NOT NULL,
|
||||
description TEXT,
|
||||
topics INT NOT NULL CHECK(topics >= 0),
|
||||
posts INT NOT NULL CHECK(posts >= 0),
|
||||
last_post BIGINT NULL,
|
||||
user_post BOOLEAN NOT NULL DEFAULT TRUE,
|
||||
admin_only BOOLEAN NOT NULL DEFAULT FALSE
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX forum_unique ON main.f_forum (category, forder);
|
||||
CREATE INDEX forum_last_post ON main.f_forum (last_post);
|
||||
|
||||
GRANT SELECT,UPDATE,INSERT ON TABLE main.f_forum TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON main.f_forum_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Topics
|
||||
--
|
||||
CREATE TABLE main.f_topic (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
forum INT NOT NULL REFERENCES main.f_forum (id) ON DELETE CASCADE,
|
||||
first_post BIGINT NOT NULL,
|
||||
last_post BIGINT NULL,
|
||||
sticky BOOLEAN NOT NULL DEFAULT FALSE,
|
||||
deleted INT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX topic_forum ON main.f_topic (forum);
|
||||
CREATE INDEX topic_fpost ON main.f_topic (first_post);
|
||||
CREATE INDEX topic_lpost ON main.f_topic (last_post);
|
||||
|
||||
GRANT SELECT,INSERT,DELETE,UPDATE ON TABLE main.f_topic TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON main.f_topic_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Posts
|
||||
--
|
||||
CREATE TABLE main.f_post (
|
||||
id BIGSERIAL PRIMARY KEY,
|
||||
forum INT NOT NULL REFERENCES main.f_forum (id) ON DELETE CASCADE,
|
||||
topic BIGINT NULL REFERENCES main.f_topic (id) ON DELETE CASCADE,
|
||||
author BIGINT NOT NULL REFERENCES main.account (id),
|
||||
reply_to BIGINT NULL REFERENCES main.f_post (id) ON DELETE SET NULL,
|
||||
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 NULL,
|
||||
edited_by BIGINT NULL REFERENCES main.account (id),
|
||||
deleted INT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX post_forum ON main.f_post (forum);
|
||||
CREATE INDEX post_topic ON main.f_post (topic);
|
||||
CREATE INDEX post_author ON main.f_post (author);
|
||||
CREATE INDEX post_editor ON main.f_post (edited_by);
|
||||
CREATE INDEX post_reply ON main.f_post (reply_to);
|
||||
|
||||
ALTER TABLE main.f_forum ADD FOREIGN KEY (last_post) REFERENCES main.f_post (id) ON DELETE SET NULL;
|
||||
ALTER TABLE main.f_topic ADD FOREIGN KEY (first_post) REFERENCES main.f_post (id) ON DELETE CASCADE;
|
||||
ALTER TABLE main.f_topic ADD FOREIGN KEY (last_post) REFERENCES main.f_post (id) ON DELETE SET NULL;
|
||||
|
||||
GRANT SELECT,INSERT,DELETE,UPDATE ON TABLE main.f_post TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON main.f_post_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Read topics
|
||||
--
|
||||
CREATE TABLE main.f_read (
|
||||
reader BIGINT NOT NULL REFERENCES main.account (id),
|
||||
topic BIGINT NOT NULL REFERENCES main.f_topic (id) ON DELETE CASCADE,
|
||||
PRIMARY KEY (reader, topic)
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT,DELETE,UPDATE ON TABLE main.f_read TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Smileys and forum codes
|
||||
--
|
||||
CREATE TABLE main.f_smiley (
|
||||
smiley VARCHAR(20) NOT NULL PRIMARY KEY,
|
||||
file VARCHAR(20) NOT NULL
|
||||
);
|
||||
CREATE TABLE main.f_code (
|
||||
p_reg_exp VARCHAR(40) NOT NULL PRIMARY KEY,
|
||||
replacement VARCHAR(80) NOT NULL
|
||||
);
|
||||
GRANT SELECT ON main.f_smiley TO legacyworlds;
|
||||
GRANT SELECT ON main.f_code TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Admins, mods, losers
|
||||
-- Not everything is useful in the current version so meh.
|
||||
--
|
||||
CREATE TABLE main.f_admin (
|
||||
"user" BIGINT NOT NULL REFERENCES main.account (id) PRIMARY KEY,
|
||||
category INT NULL REFERENCES main.f_category (id) ON DELETE CASCADE
|
||||
);
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON main.f_admin TO legacyworlds;
|
||||
|
||||
CREATE TABLE main.f_moderator (
|
||||
"user" BIGINT NOT NULL REFERENCES main.account (id) PRIMARY KEY,
|
||||
forum INT NULL REFERENCES main.f_forum (id) ON DELETE CASCADE
|
||||
);
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON main.f_moderator TO legacyworlds;
|
69
sql/13-main-links.sql
Normal file
69
sql/13-main-links.sql
Normal file
|
@ -0,0 +1,69 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 13-main-links.sql
|
||||
--
|
||||
-- Tables for the links to external sites
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- Connect to the database
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Categories
|
||||
--
|
||||
CREATE TABLE main.lk_category (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
position INT NOT NULL UNIQUE CHECK(position >= 0),
|
||||
title VARCHAR(64) NOT NULL UNIQUE,
|
||||
description TEXT
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON TABLE main.lk_category TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON main.lk_category_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Links
|
||||
--
|
||||
CREATE TABLE main.lk_link (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
category BIGINT NOT NULL REFERENCES main.lk_category (id) ON DELETE CASCADE,
|
||||
title VARCHAR(64) NOT NULL,
|
||||
url VARCHAR(128) NOT NULL UNIQUE,
|
||||
description TEXT
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX lk_link_cat_title ON main.lk_link (category, title);
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON TABLE main.lk_link TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON main.lk_link_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Reports of broken links
|
||||
--
|
||||
CREATE TABLE main.lk_broken (
|
||||
link BIGINT NOT NULL REFERENCES main.lk_link (id) ON DELETE CASCADE,
|
||||
reported_by BIGINT NOT NULL REFERENCES main.account (id),
|
||||
PRIMARY KEY (link, reported_by)
|
||||
);
|
||||
GRANT SELECT,INSERT,DELETE ON TABLE main.lk_broken TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Submitted links
|
||||
--
|
||||
CREATE TABLE main.lk_submitted (
|
||||
url VARCHAR(128) NOT NULL,
|
||||
submitted_by BIGINT NOT NULL REFERENCES main.account (id),
|
||||
title VARCHAR(64) NOT NULL,
|
||||
description TEXT,
|
||||
PRIMARY KEY (url, submitted_by)
|
||||
);
|
||||
GRANT SELECT,INSERT,DELETE ON TABLE main.lk_submitted TO legacyworlds;
|
66
sql/13-main-manual.sql
Normal file
66
sql/13-main-manual.sql
Normal file
|
@ -0,0 +1,66 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 13-main-manual.sql
|
||||
--
|
||||
-- Tables for the manual and its index
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- Connect to the database
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Manual sections
|
||||
--
|
||||
CREATE TABLE main.man_section (
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY,
|
||||
version VARCHAR(16) NOT NULL,
|
||||
lang VARCHAR(4) NOT NULL REFERENCES main.lang (txt),
|
||||
in_section BIGINT REFERENCES main.man_section (id) ON DELETE SET NULL,
|
||||
after_section BIGINT REFERENCES main.man_section (id) ON DELETE SET NULL,
|
||||
link_to BIGINT REFERENCES main.man_section (id) ON DELETE SET NULL,
|
||||
name VARCHAR(64) NOT NULL,
|
||||
last_update INT NOT NULL,
|
||||
is_page BOOLEAN NOT NULL,
|
||||
in_menu BOOLEAN NOT NULL,
|
||||
title VARCHAR(128) NOT NULL,
|
||||
contents TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX man_section_unique ON main.man_section (version, lang, name);
|
||||
CREATE INDEX man_section_in_section ON main.man_section (in_section);
|
||||
CREATE INDEX man_section_after_section ON main.man_section (after_section);
|
||||
CREATE INDEX man_section_link_to ON main.man_section (link_to);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON TABLE main.man_section TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON main.man_section_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Manual index
|
||||
--
|
||||
CREATE TABLE main.man_index (
|
||||
word VARCHAR(32) NOT NULL,
|
||||
wcount INT NOT NULL CHECK(wcount > 0),
|
||||
lang VARCHAR(4) NOT NULL REFERENCES main.lang (txt),
|
||||
section BIGINT NOT NULL REFERENCES main.man_section (id) ON DELETE CASCADE,
|
||||
PRIMARY KEY (word, lang, section)
|
||||
);
|
||||
GRANT SELECT,INSERT,DELETE ON TABLE main.man_index TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Banned words
|
||||
--
|
||||
CREATE TABLE main.man_index_ban (
|
||||
lang VARCHAR(4) NOT NULL REFERENCES main.lang (txt),
|
||||
word VARCHAR(32) NOT NULL,
|
||||
PRIMARY KEY (lang,word)
|
||||
);
|
||||
GRANT SELECT ON TABLE main.man_index_ban TO legacyworlds;
|
25
sql/13-main-proxy.sql
Normal file
25
sql/13-main-proxy.sql
Normal file
|
@ -0,0 +1,25 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 13-main-proxy.sql
|
||||
--
|
||||
-- Table for open proxy detector's cache
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- Connect to the database
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
|
||||
--
|
||||
-- Cache table
|
||||
--
|
||||
CREATE TABLE main.proxy_detector (
|
||||
host VARCHAR(15) PRIMARY KEY,
|
||||
last_check INT NOT NULL,
|
||||
is_proxy BOOLEAN NOT NULL
|
||||
);
|
||||
GRANT SELECT,INSERT,DELETE ON main.proxy_detector TO legacyworlds;
|
34
sql/18-main-functions.sql
Normal file
34
sql/18-main-functions.sql
Normal file
|
@ -0,0 +1,34 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 18-main-functions.sql
|
||||
--
|
||||
-- Creates SQL functions to be used when registering new
|
||||
-- games
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- Connect to the database
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
|
||||
--
|
||||
-- Function that adds a ranking description for some ranking type in some language
|
||||
--
|
||||
CREATE OR REPLACE FUNCTION main.add_ranking_description (version TEXT, name TEXT, lang TEXT, title TEXT, description TEXT) RETURNS VOID AS $$
|
||||
INSERT INTO main.ranking_text (ranking, lang, name, description) VALUES (
|
||||
(SELECT id FROM main.ranking_def WHERE version=$1 AND name=$2), $3, $4, $5)
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
--
|
||||
-- Function that registers a game
|
||||
--
|
||||
CREATE OR REPLACE FUNCTION main.register_game (version TEXT, game_name TEXT) RETURNS VOID AS $$
|
||||
INSERT INTO main.ranking_game (ranking, game)
|
||||
SELECT id, $2 FROM main.ranking_def
|
||||
WHERE version = $1;
|
||||
$$ LANGUAGE SQL;
|
140
sql/19-main-values.sql
Normal file
140
sql/19-main-values.sql
Normal file
|
@ -0,0 +1,140 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 19-main-values.sql
|
||||
--
|
||||
-- Insert data into some of the main tables
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- Connect to the database in ADMIN mode
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
|
||||
--
|
||||
-- Peacekeepers AI
|
||||
--
|
||||
|
||||
INSERT INTO main.account (name, email, password, status, vac_credits, last_login, last_logout, admin)
|
||||
VALUES ('AI>Peacekeepers', 'not-a-valid-email@not-a-valid-domain.com',
|
||||
'[-jv&VCR3B-b}F75qS["lpBDk8C[v~DU78Oc}=6WROXt)b+&U7[ZbNRb[d0', 'STD', 240,
|
||||
UNIX_TIMESTAMP(NOW()), UNIX_TIMESTAMP(NOW()) + 1, 't');
|
||||
|
||||
|
||||
--
|
||||
-- Words banned from the manual's index
|
||||
--
|
||||
COPY main.man_index_ban FROM STDIN;
|
||||
en -
|
||||
en a
|
||||
en am
|
||||
en an
|
||||
en as
|
||||
en at
|
||||
en and
|
||||
en are
|
||||
en be
|
||||
en being
|
||||
en by
|
||||
en for
|
||||
en had
|
||||
en has
|
||||
en have
|
||||
en he
|
||||
en if
|
||||
en in
|
||||
en into
|
||||
en is
|
||||
en it
|
||||
en its
|
||||
en it's
|
||||
en of
|
||||
en on
|
||||
en or
|
||||
en out
|
||||
en she
|
||||
en that
|
||||
en the
|
||||
en then
|
||||
en these
|
||||
en this
|
||||
en those
|
||||
en thus
|
||||
en to
|
||||
en was
|
||||
en were
|
||||
en with
|
||||
en what
|
||||
en when
|
||||
en where
|
||||
en which
|
||||
en who
|
||||
en you
|
||||
en your
|
||||
\.
|
||||
|
||||
|
||||
COPY main.f_smiley FROM STDIN;
|
||||
:-?\\) smile
|
||||
[:;]-?p razz
|
||||
:-?D lol
|
||||
[:;]-> biggrin
|
||||
;-?\\) wink
|
||||
;-?D mrgreen
|
||||
:-?\\( sad
|
||||
:evil: evil
|
||||
:smile: smile
|
||||
:happy: smile
|
||||
:wink: wink
|
||||
:sad: sad
|
||||
:unhappy: sad
|
||||
:'\\( cry
|
||||
:cry: cry
|
||||
:crying: cry
|
||||
:grin: biggrin
|
||||
:lol: lol
|
||||
:tongue: razz
|
||||
:rofl: mrgreen
|
||||
[:;]-?\\| neutral
|
||||
:neutral: neutral
|
||||
\.
|
||||
|
||||
|
||||
COPY main.f_code FROM STDIN;
|
||||
\\[b\\](.*?)\\[\\/b\\] <b>$1</b>
|
||||
\\[u\\](.*?)\\[\\/u\\] <u>$1</u>
|
||||
\\[i\\](.*?)\\[\\/i\\] <i>$1</i>
|
||||
\\[sep(arator)?\\] <hr/>
|
||||
\\[item\\](.*?)\\[\\/item\\] <ul><li>$1</li></ul>
|
||||
\\[quote\\](.*?)\\[\\/quote\\] <blockquote class="quote">$1</blockquote>
|
||||
\\[quote=([^\\]]+)\\](.*?)\\[\\/quote\\] <blockquote class="quote"><b>$1</b> said:<br/>$2</blockquote>
|
||||
\\[link=(http[^\\]]+)\\](.+?)\\[\\/link\\] <a href="$1" target="_blank">$2</a>
|
||||
\\[code\\](.*?)\\[\\/code\\] <pre>$1</pre>
|
||||
<\\/li><\\/ul>\\s*(<br\\/>\\s*)*<ul><li> </li><li>
|
||||
\\[manual\\](.*?)\\[\\/manual\\] <a href="manual" target="_blank">$1</a>
|
||||
\\[manual=(\\w+)(#\\w+)?\\](.*?)\\[\\/manual\\] <a href="manual?p=$1$2" target="_blank">$3</a>
|
||||
\\[topic=(\\d+)\\](.*?)\\[\\/topic\\] <a href="forums?cmd=T%23G%23$1" target="_blank">$2</a>
|
||||
\.
|
||||
|
||||
|
||||
-- Connect to the database in USER mode
|
||||
\c legacyworlds legacyworlds
|
||||
|
||||
|
||||
--
|
||||
-- Default values for user preferences
|
||||
--
|
||||
COPY main.user_preferences (id, version, value) FROM STDIN;
|
||||
colour main red
|
||||
font_size main 2
|
||||
forums_nitems main 20
|
||||
forums_ntopics main 20
|
||||
forums_reversed main 1
|
||||
forums_threaded main 1
|
||||
forum_code main 1
|
||||
smileys main 1
|
||||
tooltips main 2
|
||||
\.
|
18
sql/20-credits.sql
Normal file
18
sql/20-credits.sql
Normal file
|
@ -0,0 +1,18 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 20-credits.sql
|
||||
--
|
||||
-- Initialises the tables that store credits
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TABLE main.credits (
|
||||
account BIGINT NOT NULL PRIMARY KEY REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
resources_used INT NOT NULL DEFAULT 0 CHECK(resources_used >= 0),
|
||||
credits_obtained INT NOT NULL DEFAULT 9000
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE ON TABLE main.credits TO legacyworlds;
|
57
sql/25-ctf-maps.sql
Normal file
57
sql/25-ctf-maps.sql
Normal file
|
@ -0,0 +1,57 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 25-ctf-maps.sql
|
||||
--
|
||||
-- Create the tables for predefined maps.
|
||||
--
|
||||
-- Copyright(C) 2004-2008, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
-- Connect to the database in ADMIN mode
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
|
||||
--
|
||||
-- Create the definition table
|
||||
--
|
||||
|
||||
CREATE TABLE main.ctf_map_def (
|
||||
id SERIAL PRIMARY KEY,
|
||||
name VARCHAR(32) NOT NULL UNIQUE,
|
||||
description TEXT,
|
||||
alliances INT NOT NULL CHECK(alliances > 1),
|
||||
width INT NOT NULL CHECK(width > 1),
|
||||
height INT NOT NULL CHECK(height > 1)
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON TABLE main.ctf_map_def TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON main.ctf_map_def_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Create the map table
|
||||
--
|
||||
-- sys_type is either 'S' for normal systems or '1' .. '4' for nebulae
|
||||
-- alloc_for is either 0 (target) or a number that corresponds to an alliance
|
||||
--
|
||||
|
||||
CREATE TABLE main.ctf_map_layout (
|
||||
map INT NOT NULL REFERENCES main.ctf_map_def (id) ON DELETE CASCADE,
|
||||
sys_x INT NOT NULL,
|
||||
sys_y INT NOT NULL,
|
||||
sys_type CHAR(1) NOT NULL CHECK(sys_type IN ('S', '1', '2', '3', '4')),
|
||||
alloc_for INT,
|
||||
spawn_here BOOLEAN,
|
||||
|
||||
CHECK( (sys_type = 'S' AND alloc_for IS NOT NULL)
|
||||
OR (sys_type <> 'S' AND alloc_for IS NULL) ),
|
||||
|
||||
CHECK( ((alloc_for IS NULL OR alloc_for = 0) AND spawn_here IS NULL)
|
||||
OR (alloc_for > 0 AND spawn_here IS NOT NULL) ),
|
||||
|
||||
PRIMARY KEY(map, sys_x, sys_y)
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON TABLE main.ctf_map_layout TO legacyworlds;
|
161
sql/25-death-of-rats.sql
Normal file
161
sql/25-death-of-rats.sql
Normal file
|
@ -0,0 +1,161 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 25-death-of-rats.sql
|
||||
--
|
||||
-- Tables for the AMS
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Execution logs
|
||||
--
|
||||
CREATE TABLE main.dor_exec (
|
||||
ts INT NOT NULL PRIMARY KEY,
|
||||
entries INT NOT NULL CHECK(entries >= 0),
|
||||
events INT NOT NULL CHECK(events >= 0)
|
||||
);
|
||||
GRANT SELECT,INSERT,DELETE ON main.dor_exec TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Single player log
|
||||
--
|
||||
CREATE TABLE main.dor_single(
|
||||
message VARCHAR(10) NOT NULL,
|
||||
account BIGINT NOT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
ts INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX dor_single_message ON main.dor_single (message);
|
||||
CREATE INDEX dor_single_account ON main.dor_single (account);
|
||||
CREATE INDEX dor_single_ts ON main.dor_single (ts);
|
||||
|
||||
GRANT SELECT, INSERT, DELETE ON main.dor_single TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Multiplayer log
|
||||
--
|
||||
CREATE TABLE main.dor_multi(
|
||||
message VARCHAR(10) NOT NULL,
|
||||
account1 BIGINT NOT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
account2 BIGINT NOT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
ts INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX dor_multi_message ON main.dor_multi (message);
|
||||
CREATE INDEX dor_multi_account1 ON main.dor_multi (account1);
|
||||
CREATE INDEX dor_multi_account2 ON main.dor_multi (account2);
|
||||
CREATE INDEX dor_multi_ts ON main.dor_multi (ts);
|
||||
|
||||
GRANT SELECT, INSERT, DELETE ON main.dor_multi TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Log of people who try to connect with banned accounts
|
||||
--
|
||||
CREATE TABLE main.banned_attempt (
|
||||
ip_addr VARCHAR(15) NOT NULL,
|
||||
ts INT NOT NULL DEFAULT UNIX_TIMESTAMP(NOW())
|
||||
);
|
||||
CREATE INDEX banned_attempt_ip_addr ON main.banned_attempt (ip_addr);
|
||||
CREATE INDEX banned_attempt_ts ON main.banned_attempt (ts);
|
||||
GRANT SELECT, INSERT, DELETE ON main.banned_attempt TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Log of password changes
|
||||
--
|
||||
CREATE TABLE main.pass_change (
|
||||
account BIGINT NOT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
ts INT NOT NULL DEFAULT UNIX_TIMESTAMP(NOW()),
|
||||
old_pass VARCHAR(64) NOT NULL,
|
||||
new_pass VARCHAR(64) NOT NULL
|
||||
);
|
||||
CREATE INDEX pass_change_account ON main.pass_change (account);
|
||||
CREATE INDEX pass_change_ts ON main.pass_change (ts);
|
||||
GRANT SELECT, INSERT, DELETE ON main.pass_change TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Single player "badness points"
|
||||
--
|
||||
CREATE TABLE main.dor_single_points (
|
||||
account BIGINT NOT NULL PRIMARY KEY REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
points INT NOT NULL CHECK(points > 0)
|
||||
);
|
||||
GRANT SELECT, INSERT, DELETE ON main.dor_single_points TO legacyworlds;
|
||||
|
||||
--
|
||||
-- Multiplayer "badness points"
|
||||
--
|
||||
CREATE TABLE main.dor_multi_points (
|
||||
account1 BIGINT NOT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
account2 BIGINT NOT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
points INT NOT NULL CHECK(points > 0),
|
||||
PRIMARY KEY (account1, account2)
|
||||
);
|
||||
GRANT SELECT, INSERT, DELETE ON main.dor_multi_points TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Punishments
|
||||
--
|
||||
CREATE TABLE main.dor_punishment (
|
||||
account BIGINT NOT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
other_account BIGINT NOT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
ts INT NOT NULL,
|
||||
PRIMARY KEY(account,ts)
|
||||
);
|
||||
CREATE INDEX dor_punishment_ts ON main.dor_punishment (ts);
|
||||
CREATE INDEX dor_punishment_oaccount ON main.dor_punishment (other_account);
|
||||
GRANT SELECT, INSERT, DELETE ON main.dor_punishment TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Warnings
|
||||
--
|
||||
CREATE TABLE main.dor_warning (
|
||||
account1 BIGINT NOT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
account2 BIGINT NOT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
ts INT NOT NULL,
|
||||
PRIMARY KEY(account1, account2)
|
||||
);
|
||||
CREATE INDEX dor_warning_ts ON main.dor_warning (ts);
|
||||
GRANT SELECT, INSERT, DELETE ON main.dor_warning TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- In-game checks
|
||||
--
|
||||
CREATE TABLE main.dor_ingame_check (
|
||||
account1 BIGINT NOT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
account2 BIGINT NOT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
message VARCHAR(16) NOT NULL,
|
||||
ts INT NOT NULL,
|
||||
game VARCHAR(10) NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX dor_ingame_check_ac1 ON main.dor_ingame_check (account1);
|
||||
CREATE INDEX dor_ingame_check_ac2 ON main.dor_ingame_check (account2);
|
||||
CREATE INDEX dor_ingame_check_game ON main.dor_ingame_check (game);
|
||||
CREATE INDEX dor_ingame_check_message ON main.dor_ingame_check (message);
|
||||
CREATE INDEX dor_ingame_check_ts ON main.dor_ingame_check (ts);
|
||||
|
||||
GRANT SELECT, INSERT, DELETE ON main.dor_ingame_check TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Final badness points
|
||||
--
|
||||
CREATE TABLE main.dor_final_points (
|
||||
account1 BIGINT NOT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
account2 BIGINT NOT NULL REFERENCES main.account (id) ON DELETE CASCADE,
|
||||
points INT NOT NULL CHECK(points > 0),
|
||||
PRIMARY KEY(account1, account2)
|
||||
);
|
||||
GRANT SELECT, INSERT, DELETE ON main.dor_final_points TO legacyworlds;
|
42
sql/25-predefined-alliances.sql
Normal file
42
sql/25-predefined-alliances.sql
Normal file
|
@ -0,0 +1,42 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 25-predefined-alliances.sql
|
||||
--
|
||||
-- Create the table for predefined alliances and insert
|
||||
-- its contents.
|
||||
--
|
||||
-- Copyright(C) 2004-2008, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
-- Connect to the database in ADMIN mode
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
|
||||
--
|
||||
-- Create the definition table
|
||||
--
|
||||
|
||||
CREATE TABLE main.default_alliance (
|
||||
tag VARCHAR(5) NOT NULL PRIMARY KEY,
|
||||
name VARCHAR(64) NOT NULL,
|
||||
html_color CHAR(6) NOT NULL UNIQUE
|
||||
);
|
||||
|
||||
GRANT SELECT ON main.default_alliance TO legacyworlds;
|
||||
|
||||
|
||||
--
|
||||
-- Insert default alliances
|
||||
--
|
||||
COPY main.default_alliance FROM STDIN;
|
||||
-R- Red team ff0000
|
||||
-G- Green team 00ff00
|
||||
-B- Blue team 0000ff
|
||||
-C- Teal team 007f7f
|
||||
-P- Purple team 7f007f
|
||||
-Y- Yellow team afaf00
|
||||
-O- Orange team ffaf3f
|
||||
-A- Aquamarine team 003f7f
|
||||
\.
|
13
sql/30-beta5.sql
Normal file
13
sql/30-beta5.sql
Normal file
|
@ -0,0 +1,13 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 30-beta5.sql
|
||||
--
|
||||
-- Run the Beta 5 SQL scripts
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
\i beta5/00-beta5.sql
|
||||
\i beta5/10-beta5-b5.sql
|
||||
\i beta5/11-beta5-b5m0.sql
|
33
sql/50-beta6-planet-pictures.sql
Normal file
33
sql/50-beta6-planet-pictures.sql
Normal file
|
@ -0,0 +1,33 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- 50-beta6-planet-pictures.sql
|
||||
--
|
||||
-- Tables that store votes about Beta 6's planet pictures
|
||||
--
|
||||
-- Copyright(C) 2004-2008, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
-- Connect to the database in ADMIN mode
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
|
||||
CREATE TABLE main.b6_planet_pics (
|
||||
id SERIAL PRIMARY KEY,
|
||||
p_size INT NOT NULL CHECK(p_size BETWEEN 1 AND 10),
|
||||
p_type INT NOT NULL CHECK(p_type BETWEEN 0 AND 4)
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT ON TABLE main.b6_planet_pics TO legacyworlds;
|
||||
GRANT SELECT,UPDATE ON main.b6_planet_pics_id_seq TO legacyworlds;
|
||||
|
||||
|
||||
CREATE TABLE main.b6_planet_votes (
|
||||
account BIGINT NOT NULL REFERENCES main.account (id),
|
||||
picture INT NOT NULL REFERENCES main.b6_planet_pics (id),
|
||||
vote INT NOT NULL CHECK(vote BETWEEN 1 AND 5),
|
||||
PRIMARY KEY(account, picture)
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT ON TABLE main.b6_planet_votes TO legacyworlds;
|
25
sql/INSTALL.sql
Normal file
25
sql/INSTALL.sql
Normal file
|
@ -0,0 +1,25 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- INSTALL.sql
|
||||
--
|
||||
-- Install the Legacy Worlds database
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
\i 00-init.sql
|
||||
\i 01-inheritance.sql
|
||||
\i 10-main.sql
|
||||
\i 11-main-enums.sql
|
||||
\i 12-main-tables.sql
|
||||
\i 13-main-donations.sql
|
||||
\i 13-main-forums.sql
|
||||
\i 13-main-links.sql
|
||||
\i 13-main-manual.sql
|
||||
\i 13-main-proxy.sql
|
||||
\i 18-main-functions.sql
|
||||
\i 19-main-values.sql
|
||||
\i 25-ctf-maps.sql
|
||||
\i 25-predefined-alliances.sql
|
||||
\i 30-beta5.sql
|
46
sql/beta5/00-beta5.sql
Normal file
46
sql/beta5/00-beta5.sql
Normal file
|
@ -0,0 +1,46 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/00-beta5.sql
|
||||
--
|
||||
-- Install the Beta 5-specific data into the main database
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
SET search_path=main;
|
||||
|
||||
COPY ranking_def (version, name, more) FROM STDIN;
|
||||
beta5 p_general FALSE
|
||||
beta5 a_general TRUE
|
||||
beta5 p_financial FALSE
|
||||
beta5 p_military FALSE
|
||||
beta5 p_civ FALSE
|
||||
beta5 p_round FALSE
|
||||
beta5 p_idr FALSE
|
||||
\.
|
||||
|
||||
|
||||
SELECT add_ranking_description('beta5', 'p_general', 'en', 'General Ranking',
|
||||
'This ranking corresponds to a combination of civilisation, military and financial rankings. It represents a ' ||
|
||||
'player''s current overall advancement and strength in the game.');
|
||||
SELECT add_ranking_description('beta5', 'a_general', 'en', 'Alliance Ranking',
|
||||
'An alliance''s ranking indicates its overall strength; the points for an alliance are the sum of the general ' ||
|
||||
'ranking points for all of its members.');
|
||||
SELECT add_ranking_description('beta5', 'p_financial', 'en', 'Financial Ranking',
|
||||
'This ranking corresponds to the economic health of a player''s empire. It takes into account the player''s ' ||
|
||||
'banked cash, his income and the number of industrial factories he owns.');
|
||||
SELECT add_ranking_description('beta5', 'p_military', 'en', 'Military Ranking',
|
||||
'This ranking allows to assess the military strength of a player''s empire. Its calculation is based on the ' ||
|
||||
'number of turrets and military factories the player owns along with his fleet fire power.');
|
||||
SELECT add_ranking_description('beta5', 'p_civ', 'en', 'Civilization Ranking',
|
||||
'This ranking represents the advancement level of the society in a player''s empire. It takes into account ' ||
|
||||
'technology level, population and happiness.');
|
||||
SELECT add_ranking_description('beta5', 'p_round', 'en', 'Overall Round Ranking',
|
||||
'This ranking is calculated based on players'' previous general rankings for the top 15 players. It allows ' ||
|
||||
'for a long term estimate of the bets players'' accomplishments.');
|
||||
SELECT add_ranking_description('beta5', 'p_idr', 'en', 'Inflicted Damage Ranking',
|
||||
'This ranking represents the amount of damage a player has inflicted on other players'' fleets.');
|
56
sql/beta5/10-beta5-b5.sql
Normal file
56
sql/beta5/10-beta5-b5.sql
Normal file
|
@ -0,0 +1,56 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/10-beta5.sql
|
||||
--
|
||||
-- Install the Beta 5 'b5' game database
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
-- Connect as administrator
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
-- Create the game's schema
|
||||
CREATE SCHEMA "b5";
|
||||
GRANT USAGE ON SCHEMA "b5" TO legacyworlds;
|
||||
|
||||
-- Include the files defining the game's database structure
|
||||
SET search_path="b5",main,public;
|
||||
\i beta5/structure/00-gdata.sql
|
||||
\i beta5/structure/00-system.sql
|
||||
\i beta5/structure/00-ecm-eccm.sql
|
||||
\i beta5/structure/00-rule-base.sql
|
||||
\i beta5/structure/00-player-table.sql
|
||||
\i beta5/structure/01-research-base.sql
|
||||
\i beta5/structure/01-alliance.sql
|
||||
\i beta5/structure/01-planet.sql
|
||||
\i beta5/structure/01-player-dipl.sql
|
||||
\i beta5/structure/01-player-rules.sql
|
||||
\i beta5/structure/01-message-base.sql
|
||||
\i beta5/structure/02-alliance-forums.sql
|
||||
\i beta5/structure/02-orders.sql
|
||||
\i beta5/structure/02-warehouse.sql
|
||||
\i beta5/structure/03-fleets.sql
|
||||
\i beta5/structure/04-sales.sql
|
||||
\i beta5/structure/05-message-player.sql
|
||||
\i beta5/structure/06-message-internal.sql
|
||||
\i beta5/structure/06-message-battle.sql
|
||||
\i beta5/structure/99-player-fk.sql
|
||||
|
||||
-- Include the file containing the game's read-only data
|
||||
\i beta5/data/standard.sql
|
||||
|
||||
-- Include the file containing initial game data in USER mode
|
||||
\c - legacyworlds
|
||||
SET search_path="b5",main,public;
|
||||
\i beta5/data/game.sql
|
||||
|
||||
-- Finalise the structure
|
||||
\c - legacyworlds_admin
|
||||
SET search_path="b5",main,public;
|
||||
\i beta5/structure/finalise.sql
|
||||
|
||||
-- Register the game itself
|
||||
SELECT register_game ('beta5', 'beta5');
|
56
sql/beta5/11-beta5-b5m0.sql
Normal file
56
sql/beta5/11-beta5-b5m0.sql
Normal file
|
@ -0,0 +1,56 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/11-beta5-b5m0.sql
|
||||
--
|
||||
-- Install the Beta 5 'b5m0' game database
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
-- Connect as administrator
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
-- Create the game's schema
|
||||
CREATE SCHEMA "b5m0";
|
||||
GRANT USAGE ON SCHEMA "b5m0" TO legacyworlds;
|
||||
|
||||
-- Include the files defining the game's database structure
|
||||
SET search_path="b5m0",main,public;
|
||||
\i beta5/structure/00-gdata.sql
|
||||
\i beta5/structure/00-system.sql
|
||||
\i beta5/structure/00-ecm-eccm.sql
|
||||
\i beta5/structure/00-rule-base.sql
|
||||
\i beta5/structure/00-player-table.sql
|
||||
\i beta5/structure/01-research-base.sql
|
||||
\i beta5/structure/01-alliance.sql
|
||||
\i beta5/structure/01-planet.sql
|
||||
\i beta5/structure/01-player-dipl.sql
|
||||
\i beta5/structure/01-player-rules.sql
|
||||
\i beta5/structure/01-message-base.sql
|
||||
\i beta5/structure/02-alliance-forums.sql
|
||||
\i beta5/structure/02-orders.sql
|
||||
\i beta5/structure/02-warehouse.sql
|
||||
\i beta5/structure/03-fleets.sql
|
||||
\i beta5/structure/04-sales.sql
|
||||
\i beta5/structure/05-message-player.sql
|
||||
\i beta5/structure/06-message-internal.sql
|
||||
\i beta5/structure/06-message-battle.sql
|
||||
\i beta5/structure/99-player-fk.sql
|
||||
|
||||
-- Include the file containing the game's read-only data
|
||||
\i beta5/data/match.sql
|
||||
|
||||
-- Include the file containing initial game data in USER mode
|
||||
\c - legacyworlds
|
||||
SET search_path="b5m0",main,public;
|
||||
\i beta5/data/game.sql
|
||||
|
||||
-- Finalise the structure
|
||||
\c - legacyworlds_admin
|
||||
SET search_path="b5m0",main,public;
|
||||
\i beta5/structure/finalise.sql
|
||||
|
||||
-- Register the game itself
|
||||
SELECT register_game ('beta5', 'b5match');
|
61
sql/beta5/beta5-ctf.sql
Normal file
61
sql/beta5/beta5-ctf.sql
Normal file
|
@ -0,0 +1,61 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/beta5-match.sql
|
||||
--
|
||||
-- Generic installation script for matches, to be parsed
|
||||
-- by administrative scripts
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
-- Connect as administrator
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
-- Create the game's schema
|
||||
CREATE SCHEMA "b5mX";
|
||||
GRANT USAGE ON SCHEMA "b5mX" TO legacyworlds;
|
||||
|
||||
-- Include the files defining the game's database structure
|
||||
SET search_path="b5mX",main,public;
|
||||
\i beta5/structure/00-gdata.sql
|
||||
\i beta5/structure/00-system.sql
|
||||
\i beta5/structure/00-ecm-eccm.sql
|
||||
\i beta5/structure/00-rule-base.sql
|
||||
\i beta5/structure/00-player-table.sql
|
||||
\i beta5/structure/01-research-base.sql
|
||||
\i beta5/structure/01-alliance.sql
|
||||
\i beta5/structure/01-planet.sql
|
||||
\i beta5/structure/01-player-dipl.sql
|
||||
\i beta5/structure/01-player-rules.sql
|
||||
\i beta5/structure/01-message-base.sql
|
||||
\i beta5/structure/02-alliance-forums.sql
|
||||
\i beta5/structure/02-alliance-tech.sql
|
||||
\i beta5/structure/02-orders.sql
|
||||
\i beta5/structure/02-warehouse.sql
|
||||
\i beta5/structure/03-fleets.sql
|
||||
\i beta5/structure/04-sales.sql
|
||||
\i beta5/structure/05-message-player.sql
|
||||
\i beta5/structure/06-message-internal.sql
|
||||
\i beta5/structure/06-message-battle.sql
|
||||
\i beta5/structure/07-message-admin.sql
|
||||
\i beta5/structure/07-beacons.sql
|
||||
\i beta5/structure/10-ctf-tables.sql
|
||||
\i beta5/structure/99-player-fk.sql
|
||||
|
||||
-- Include the file containing the game's read-only data
|
||||
\i beta5/data/match.sql
|
||||
|
||||
-- Include the file containing initial game data in USER mode
|
||||
\c - legacyworlds
|
||||
SET search_path="b5mX",main,public;
|
||||
\i beta5/data/game.sql
|
||||
|
||||
-- Finalise the structure
|
||||
\c - legacyworlds_admin
|
||||
SET search_path="b5mX",main,public;
|
||||
\i beta5/structure/finalise.sql
|
||||
|
||||
-- Register the game itself
|
||||
SELECT register_game ('beta5', 'b5mX');
|
60
sql/beta5/beta5-match.sql
Normal file
60
sql/beta5/beta5-match.sql
Normal file
|
@ -0,0 +1,60 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/beta5-match.sql
|
||||
--
|
||||
-- Generic installation script for matches, to be parsed
|
||||
-- by administrative scripts
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
-- Connect as administrator
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
-- Create the game's schema
|
||||
CREATE SCHEMA "b5mX";
|
||||
GRANT USAGE ON SCHEMA "b5mX" TO legacyworlds;
|
||||
|
||||
-- Include the files defining the game's database structure
|
||||
SET search_path="b5mX",main,public;
|
||||
\i beta5/structure/00-gdata.sql
|
||||
\i beta5/structure/00-system.sql
|
||||
\i beta5/structure/00-ecm-eccm.sql
|
||||
\i beta5/structure/00-rule-base.sql
|
||||
\i beta5/structure/00-player-table.sql
|
||||
\i beta5/structure/01-research-base.sql
|
||||
\i beta5/structure/01-alliance.sql
|
||||
\i beta5/structure/01-planet.sql
|
||||
\i beta5/structure/01-player-dipl.sql
|
||||
\i beta5/structure/01-player-rules.sql
|
||||
\i beta5/structure/01-message-base.sql
|
||||
\i beta5/structure/02-alliance-forums.sql
|
||||
\i beta5/structure/02-alliance-tech.sql
|
||||
\i beta5/structure/02-orders.sql
|
||||
\i beta5/structure/02-warehouse.sql
|
||||
\i beta5/structure/03-fleets.sql
|
||||
\i beta5/structure/04-sales.sql
|
||||
\i beta5/structure/05-message-player.sql
|
||||
\i beta5/structure/06-message-internal.sql
|
||||
\i beta5/structure/06-message-battle.sql
|
||||
\i beta5/structure/07-message-admin.sql
|
||||
\i beta5/structure/07-beacons.sql
|
||||
\i beta5/structure/99-player-fk.sql
|
||||
|
||||
-- Include the file containing the game's read-only data
|
||||
\i beta5/data/match.sql
|
||||
|
||||
-- Include the file containing initial game data in USER mode
|
||||
\c - legacyworlds
|
||||
SET search_path="b5mX",main,public;
|
||||
\i beta5/data/game.sql
|
||||
|
||||
-- Finalise the structure
|
||||
\c - legacyworlds_admin
|
||||
SET search_path="b5mX",main,public;
|
||||
\i beta5/structure/finalise.sql
|
||||
|
||||
-- Register the game itself
|
||||
SELECT register_game ('beta5', 'b5mX');
|
61
sql/beta5/beta5-round.sql
Normal file
61
sql/beta5/beta5-round.sql
Normal file
|
@ -0,0 +1,61 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/beta5-round.sql
|
||||
--
|
||||
-- Generic installation script for rounds, to be parsed
|
||||
-- by administrative scripts
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
-- Connect as administrator
|
||||
\c legacyworlds legacyworlds_admin
|
||||
|
||||
-- Create the game's schema
|
||||
CREATE SCHEMA "b5rX";
|
||||
GRANT USAGE ON SCHEMA "b5rX" TO legacyworlds;
|
||||
|
||||
-- Include the files defining the game's database structure
|
||||
SET search_path="b5rX",main,public;
|
||||
\i beta5/structure/00-gdata.sql
|
||||
\i beta5/structure/00-system.sql
|
||||
\i beta5/structure/00-ecm-eccm.sql
|
||||
\i beta5/structure/00-rule-base.sql
|
||||
\i beta5/structure/00-player-table.sql
|
||||
\i beta5/structure/01-research-base.sql
|
||||
\i beta5/structure/01-alliance.sql
|
||||
\i beta5/structure/01-planet.sql
|
||||
\i beta5/structure/01-player-dipl.sql
|
||||
\i beta5/structure/01-player-rules.sql
|
||||
\i beta5/structure/01-message-base.sql
|
||||
\i beta5/structure/02-alliance-forums.sql
|
||||
\i beta5/structure/02-alliance-tech.sql
|
||||
\i beta5/structure/02-orders.sql
|
||||
\i beta5/structure/02-warehouse.sql
|
||||
\i beta5/structure/03-fleets.sql
|
||||
\i beta5/structure/04-sales.sql
|
||||
\i beta5/structure/05-message-player.sql
|
||||
\i beta5/structure/06-message-internal.sql
|
||||
\i beta5/structure/06-message-battle.sql
|
||||
\i beta5/structure/07-message-admin.sql
|
||||
\i beta5/structure/07-beacons.sql
|
||||
\i beta5/structure/10-prot-tables.sql
|
||||
\i beta5/structure/99-player-fk.sql
|
||||
|
||||
-- Include the file containing the game's read-only data
|
||||
\i beta5/data/standard.sql
|
||||
|
||||
-- Include the file containing initial game data in USER mode
|
||||
\c - legacyworlds
|
||||
SET search_path="b5rX",main,public;
|
||||
\i beta5/data/game.sql
|
||||
|
||||
-- Finalise the structure
|
||||
\c - legacyworlds_admin
|
||||
SET search_path="b5rX",main,public;
|
||||
\i beta5/structure/finalise.sql
|
||||
|
||||
-- Register the game itself
|
||||
SELECT register_game ('beta5', 'b5rX');
|
15
sql/beta5/data/game.sql
Normal file
15
sql/beta5/data/game.sql
Normal file
|
@ -0,0 +1,15 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/structure/game.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- User-mode data insertion
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
-- Universe generator parameters
|
||||
INSERT INTO gdata (id, value) VALUES ('sg_dir', '0');
|
||||
INSERT INTO gdata (id, value) VALUES ('sg_len', '0');
|
602
sql/beta5/data/match.sql
Normal file
602
sql/beta5/data/match.sql
Normal file
|
@ -0,0 +1,602 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/data/readonly.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Read-only data insertion
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
-- ECM probability table
|
||||
COPY ecm FROM STDIN;
|
||||
0 1 0
|
||||
0 2 0
|
||||
0 3 0
|
||||
0 4 1
|
||||
0 5 99
|
||||
1 1 0
|
||||
1 2 0
|
||||
1 3 10
|
||||
1 4 70
|
||||
1 5 20
|
||||
2 1 0
|
||||
2 2 10
|
||||
2 3 70
|
||||
2 4 15
|
||||
2 5 5
|
||||
3 1 5
|
||||
3 2 70
|
||||
3 3 15
|
||||
3 4 8
|
||||
3 5 2
|
||||
4 1 60
|
||||
4 2 30
|
||||
4 3 6
|
||||
4 4 4
|
||||
4 5 0
|
||||
\.
|
||||
|
||||
-- ECCM probability table
|
||||
COPY eccm FROM STDIN;
|
||||
0 0 99
|
||||
0 1 1
|
||||
0 2 0
|
||||
0 3 0
|
||||
0 4 0
|
||||
1 0 20
|
||||
1 1 70
|
||||
1 2 10
|
||||
1 3 0
|
||||
1 4 0
|
||||
2 0 10
|
||||
2 1 20
|
||||
2 2 60
|
||||
2 3 10
|
||||
2 4 0
|
||||
3 0 5
|
||||
3 1 10
|
||||
3 2 20
|
||||
3 3 60
|
||||
3 4 5
|
||||
4 0 0
|
||||
4 1 5
|
||||
4 2 10
|
||||
4 3 40
|
||||
4 4 45
|
||||
\.
|
||||
|
||||
|
||||
|
||||
-- Default rules
|
||||
COPY rule_def FROM stdin;
|
||||
military_level 0
|
||||
pop_growth_factor 2
|
||||
if_productivity 30
|
||||
if_productivity_factor 10
|
||||
base_income 3
|
||||
factory_cost 10
|
||||
turret_cost 20
|
||||
mf_productivity 12
|
||||
mf_productivity_factor 10
|
||||
workunits_turret 1500
|
||||
workunits_gaship 4500
|
||||
workunits_fighter 2000
|
||||
workunits_cruiser 20000
|
||||
workunits_bcruiser 22000
|
||||
build_cost_turret 400
|
||||
build_cost_gaship 750
|
||||
build_cost_fighter 500
|
||||
build_cost_cruiser 5000
|
||||
build_cost_bcruiser 15000
|
||||
if_cost 400
|
||||
mf_cost 400
|
||||
battle_losses 100
|
||||
unhappiness_factor 95
|
||||
effective_fleet_power 100
|
||||
planet_max_pop 10000
|
||||
capital_ship_speed 1
|
||||
prevent_hs_exit 0
|
||||
planet_destruction 0
|
||||
turret_power 10
|
||||
gaship_power 5
|
||||
fighter_power 10
|
||||
cruiser_power 40
|
||||
bcruiser_power 80
|
||||
gaship_upkeep 40
|
||||
fighter_upkeep 50
|
||||
cruiser_upkeep 500
|
||||
bcruiser_upkeep 1500
|
||||
research_percent 350
|
||||
gaship_space 3
|
||||
fighter_space 1
|
||||
cruiser_haul 20
|
||||
bcruiser_haul 15
|
||||
ecm_level 0
|
||||
eccm_level 0
|
||||
gaship_pop 200
|
||||
hs_beacon_level 0
|
||||
probe_tech 0
|
||||
\.
|
||||
|
||||
|
||||
-- Rule handlers
|
||||
COPY rule_handler FROM STDIN;
|
||||
unhappiness_factor UpdateHappiness
|
||||
planet_max_pop UpdateMaxPopulation
|
||||
effective_fleet_power UpdateFleetPower
|
||||
gaship_power UpdateFleetPower
|
||||
fighter_power UpdateFleetPower
|
||||
cruiser_power UpdateFleetPower
|
||||
bcruiser_power UpdateFleetPower
|
||||
ecm_level UpdateCommTech
|
||||
eccm_level UpdateCommTech
|
||||
\.
|
||||
|
||||
|
||||
-- Research definitions
|
||||
COPY research FROM STDIN;
|
||||
1 7000 50000 0 1 FALSE
|
||||
2 5000 15000 0 0 FALSE
|
||||
3 4000 20000 0 2 FALSE
|
||||
4 6000 30000 0 2 FALSE
|
||||
5 13333 5000 0 1 TRUE
|
||||
6 29000 300000 0 1 FALSE
|
||||
7 44667 50000 0 2 TRUE
|
||||
8 10333 40000 0 2 FALSE
|
||||
9 10333 40000 0 2 FALSE
|
||||
10 18000 50000 0 2 FALSE
|
||||
11 18000 50000 0 0 FALSE
|
||||
12 38000 80000 2 2 FALSE
|
||||
13 57667 15000 1 2 TRUE
|
||||
14 54000 100000 1 0 FALSE
|
||||
15 37554 100000 1 2 FALSE
|
||||
16 14667 100000 0 0 FALSE
|
||||
17 34889 100000 1 0 FALSE
|
||||
18 21777 150000 1 0 FALSE
|
||||
20 99628 500000 1 2 FALSE
|
||||
21 211873 1000000 2 2 FALSE
|
||||
22 99628 500000 1 0 FALSE
|
||||
23 51519 30000 1 0 TRUE
|
||||
24 28777 100000 1 2 FALSE
|
||||
25 87925 500000 1 0 FALSE
|
||||
26 23777 100000 2 1 FALSE
|
||||
27 135777 500000 1 0 FALSE
|
||||
28 241036 800000 1 0 FALSE
|
||||
29 112000 200000 1 2 FALSE
|
||||
30 68000 1500000 2 2 FALSE
|
||||
31 44000 400000 1 2 FALSE
|
||||
32 68667 60000 1 2 TRUE
|
||||
33 300000 400000 2 2 FALSE
|
||||
34 174333 80000 1 2 TRUE
|
||||
35 127036 800000 2 2 FALSE
|
||||
36 72146 600000 1 2 FALSE
|
||||
37 68369 300000 1 2 FALSE
|
||||
38 98072 500000 1 1 FALSE
|
||||
39 212466 700000 2 1 FALSE
|
||||
40 172837 1000000 1 0 FALSE
|
||||
41 280449 2000000 1 0 FALSE
|
||||
42 554218 1500000 1 2 FALSE
|
||||
43 860476 100000 1 0 TRUE
|
||||
44 49036 500000 2 1 FALSE
|
||||
45 49036 500000 1 1 FALSE
|
||||
46 112048 1000000 2 2 FALSE
|
||||
48 238218 1500000 1 1 FALSE
|
||||
49 238218 1500000 1 1 FALSE
|
||||
50 160195 800000 1 2 FALSE
|
||||
51 302260 1500000 2 1 FALSE
|
||||
52 875013 3000000 2 1 FALSE
|
||||
53 342195 1500000 1 0 FALSE
|
||||
54 839548 2000000 1 1 FALSE
|
||||
55 517576 2000000 1 2 FALSE
|
||||
56 740101 70000 1 2 TRUE
|
||||
57 263996 1500000 1 0 FALSE
|
||||
58 241036 1500000 1 0 FALSE
|
||||
59 403005 120000 1 2 TRUE
|
||||
61 136195 500000 1 1 FALSE
|
||||
62 1106581 2500000 1 2 FALSE
|
||||
63 583758 2500000 1 1 FALSE
|
||||
64 628073 5000000 1 1 FALSE
|
||||
65 628073 5000000 1 1 FALSE
|
||||
68 319418 2000000 1 1 FALSE
|
||||
69 1019937 150000 1 1 TRUE
|
||||
70 1949373 5000000 1 0 FALSE
|
||||
71 630811 4000000 2 1 FALSE
|
||||
72 529228 2500000 2 0 FALSE
|
||||
73 965308 3800000 1 2 FALSE
|
||||
74 1295217 4000000 1 2 FALSE
|
||||
75 2537057 7000000 1 2 FALSE
|
||||
76 3725240 200000 1 2 TRUE
|
||||
77 2228337 10000000 1 1 FALSE
|
||||
78 1251897 4000000 1 2 FALSE
|
||||
79 845313 4000000 1 0 FALSE
|
||||
80 2719164 10000000 1 1 FALSE
|
||||
81 2709164 10000000 1 2 FALSE
|
||||
82 3616595 12000000 1 1 FALSE
|
||||
83 4321117 10000000 1 2 FALSE
|
||||
84 805637 5000000 1 1 FALSE
|
||||
85 2088549 8000000 1 1 FALSE
|
||||
86 4642983 12000000 1 1 FALSE
|
||||
87 3642219 170000 1 2 TRUE
|
||||
88 7457771 15000000 1 1 FALSE
|
||||
89 4000692 10000000 1 1 FALSE
|
||||
90 2627540 10000000 1 1 FALSE
|
||||
\.
|
||||
|
||||
|
||||
-- Research dependencies
|
||||
COPY research_dep FROM STDIN;
|
||||
5 1
|
||||
6 1
|
||||
6 2
|
||||
16 2
|
||||
46 2
|
||||
8 3
|
||||
9 3
|
||||
17 3
|
||||
10 4
|
||||
11 4
|
||||
38 4
|
||||
7 6
|
||||
51 6
|
||||
63 6
|
||||
71 6
|
||||
15 8
|
||||
18 8
|
||||
36 8
|
||||
15 9
|
||||
24 9
|
||||
26 9
|
||||
27 9
|
||||
14 10
|
||||
30 10
|
||||
50 10
|
||||
12 11
|
||||
30 11
|
||||
31 11
|
||||
13 12
|
||||
27 14
|
||||
29 14
|
||||
20 15
|
||||
22 15
|
||||
38 15
|
||||
17 16
|
||||
20 16
|
||||
22 16
|
||||
25 16
|
||||
23 17
|
||||
43 17
|
||||
21 18
|
||||
44 18
|
||||
45 18
|
||||
68 46
|
||||
21 20
|
||||
42 20
|
||||
48 20
|
||||
76 21
|
||||
40 22
|
||||
49 22
|
||||
57 22
|
||||
25 24
|
||||
35 24
|
||||
36 24
|
||||
37 24
|
||||
72 25
|
||||
39 26
|
||||
28 27
|
||||
53 27
|
||||
58 27
|
||||
42 28
|
||||
55 28
|
||||
33 29
|
||||
34 29
|
||||
33 30
|
||||
32 31
|
||||
35 31
|
||||
52 33
|
||||
73 35
|
||||
50 36
|
||||
55 36
|
||||
61 36
|
||||
53 37
|
||||
57 37
|
||||
63 37
|
||||
39 38
|
||||
71 38
|
||||
54 39
|
||||
41 40
|
||||
64 40
|
||||
65 40
|
||||
63 41
|
||||
70 41
|
||||
73 41
|
||||
79 41
|
||||
43 42
|
||||
62 42
|
||||
74 42
|
||||
49 44
|
||||
59 44
|
||||
46 45
|
||||
48 45
|
||||
59 48
|
||||
62 48
|
||||
65 48
|
||||
64 49
|
||||
51 50
|
||||
52 51
|
||||
54 53
|
||||
74 53
|
||||
78 53
|
||||
56 55
|
||||
75 55
|
||||
72 57
|
||||
73 57
|
||||
71 58
|
||||
77 58
|
||||
79 58
|
||||
68 61
|
||||
69 61
|
||||
85 61
|
||||
70 62
|
||||
69 63
|
||||
89 63
|
||||
90 63
|
||||
86 64
|
||||
82 65
|
||||
80 70
|
||||
81 70
|
||||
82 70
|
||||
89 71
|
||||
78 72
|
||||
84 72
|
||||
83 73
|
||||
75 74
|
||||
77 74
|
||||
83 74
|
||||
85 74
|
||||
76 75
|
||||
90 78
|
||||
83 79
|
||||
89 79
|
||||
86 80
|
||||
88 80
|
||||
87 81
|
||||
88 81
|
||||
89 84
|
||||
\.
|
||||
|
||||
|
||||
-- Research effects
|
||||
COPY research_effect FROM STDIN;
|
||||
1 military_level 1
|
||||
3 battle_losses -2
|
||||
4 if_cost 80
|
||||
4 if_productivity_factor 2
|
||||
5 if_productivity_factor -2
|
||||
5 mf_productivity_factor 3
|
||||
5 unhappiness_factor 5
|
||||
6 military_level 1
|
||||
7 effective_fleet_power -5
|
||||
7 unhappiness_factor -4
|
||||
8 if_cost 40
|
||||
8 if_productivity_factor 1
|
||||
8 mf_cost 40
|
||||
8 mf_productivity_factor 1
|
||||
9 if_cost 40
|
||||
9 if_productivity_factor 1
|
||||
9 mf_cost 40
|
||||
9 mf_productivity_factor 1
|
||||
10 pop_growth_factor 1
|
||||
12 unhappiness_factor -1
|
||||
13 if_productivity_factor -2
|
||||
13 mf_productivity_factor -3
|
||||
13 unhappiness_factor -5
|
||||
15 research_percent 10
|
||||
17 research_percent 10
|
||||
18 unhappiness_factor -2
|
||||
20 research_percent 10
|
||||
21 base_income 2
|
||||
23 base_income -1
|
||||
23 if_productivity_factor -2
|
||||
23 research_percent 25
|
||||
24 battle_losses -5
|
||||
24 if_cost 80
|
||||
24 if_productivity_factor 2
|
||||
24 mf_cost 80
|
||||
24 mf_productivity_factor 2
|
||||
26 gaship_pop 75
|
||||
29 if_cost 120
|
||||
29 if_productivity_factor 3
|
||||
30 pop_growth_factor 1
|
||||
31 if_productivity_factor -1
|
||||
31 mf_productivity_factor -1
|
||||
31 unhappiness_factor -2
|
||||
32 if_productivity_factor -1
|
||||
32 mf_productivity_factor -1
|
||||
32 unhappiness_factor -4
|
||||
33 pop_growth_factor 1
|
||||
34 pop_growth_factor 1
|
||||
34 unhappiness_factor 5
|
||||
35 planet_max_pop 10000
|
||||
36 if_cost 120
|
||||
36 if_productivity_factor 3
|
||||
36 mf_cost 120
|
||||
36 mf_productivity_factor 3
|
||||
37 battle_losses -5
|
||||
37 if_cost 80
|
||||
37 if_productivity_factor 2
|
||||
37 mf_cost 80
|
||||
37 mf_productivity_factor 2
|
||||
38 effective_fleet_power 10
|
||||
39 gaship_pop 75
|
||||
41 capital_ship_speed 1
|
||||
42 research_percent 10
|
||||
43 if_productivity_factor -3
|
||||
43 mf_productivity_factor -3
|
||||
43 research_percent 50
|
||||
44 ecm_level 1
|
||||
45 eccm_level 1
|
||||
46 hs_beacon_level 1
|
||||
48 eccm_level 1
|
||||
49 ecm_level 1
|
||||
51 battle_losses -2
|
||||
52 battle_losses -2
|
||||
53 battle_losses -2
|
||||
53 if_cost 80
|
||||
53 if_productivity_factor 2
|
||||
53 mf_cost 80
|
||||
53 mf_productivity_factor 2
|
||||
54 gaship_pop 75
|
||||
55 if_cost 80
|
||||
55 if_productivity_factor 2
|
||||
55 mf_cost 80
|
||||
55 mf_productivity_factor 2
|
||||
55 unhappiness_factor 7
|
||||
56 if_productivity_factor -2
|
||||
56 mf_productivity_factor -2
|
||||
56 unhappiness_factor -7
|
||||
57 battle_losses -4
|
||||
59 eccm_level -1
|
||||
59 ecm_level -1
|
||||
59 unhappiness_factor -4
|
||||
61 turret_power 3
|
||||
62 research_percent 10
|
||||
63 military_level 1
|
||||
64 ecm_level 1
|
||||
65 eccm_level 1
|
||||
68 turret_power 3
|
||||
69 if_productivity_factor -4
|
||||
69 mf_productivity_factor 6
|
||||
69 unhappiness_factor 10
|
||||
70 capital_ship_speed 1
|
||||
71 fighter_power 4
|
||||
71 gaship_power 2
|
||||
73 planet_max_pop 10000
|
||||
74 battle_losses -2
|
||||
74 if_cost 80
|
||||
74 if_productivity_factor 2
|
||||
74 mf_cost 80
|
||||
74 mf_productivity_factor 2
|
||||
75 if_cost 160
|
||||
75 if_productivity_factor 4
|
||||
75 mf_cost 120
|
||||
75 mf_productivity_factor 3
|
||||
76 base_income 3
|
||||
76 if_productivity_factor 10
|
||||
76 mf_productivity_factor -5
|
||||
76 research_percent -50
|
||||
76 unhappiness_factor 15
|
||||
77 battle_losses -5
|
||||
78 if_cost 80
|
||||
78 if_productivity_factor 2
|
||||
78 mf_cost 80
|
||||
78 mf_productivity_factor 2
|
||||
80 prevent_hs_exit 1
|
||||
81 if_productivity_factor -3
|
||||
81 unhappiness_factor -5
|
||||
82 eccm_level 1
|
||||
83 planet_max_pop 10000
|
||||
84 capital_ship_speed 1
|
||||
84 effective_fleet_power 5
|
||||
85 turret_power 3
|
||||
86 ecm_level 1
|
||||
87 if_cost 120
|
||||
87 if_productivity_factor 3
|
||||
87 unhappiness_factor 7
|
||||
88 planet_destruction 1
|
||||
89 bcruiser_power 20
|
||||
89 cruiser_power 10
|
||||
90 effective_fleet_power 10
|
||||
\.
|
||||
|
||||
|
||||
-- Research descriptions
|
||||
COPY research_txt FROM STDIN;
|
||||
1 en Fighters Sir! We have successfully researched a new type of ship, the Fighter! These ships are faster and more efficient at combating enemy ships than our current Ground Assault ships.
|
||||
2 en Hyperspace Basics Sir! Our scientists have made major progress in understanding the basics behind Hyperspace theory. Those basic hyperspace capabilities are the very beginning of a new area in space flight and allow a wide range of new experiments.
|
||||
3 en Advanced Materials Sir! Our scientists just discovered new production methods that will allow us to create hardened materials! Our factories must be upgraded in order to start producing those new alloys.
|
||||
4 en Bio-engineering Sir! Our scientists worked hard to improve our empire's knowledge of bio-engineering, which will greatly improve the production of basic goods, as well as pave the way for further advances.
|
||||
5 en Martial law Sir! We can enact Martial Law to force our people to work in the military's best interest! They probably won''t be too happy about it, and our economy might suffer, but who cares? Our military production will be greatly improved!
|
||||
6 en Cruisers Sir! We have successfully researched a new type of ship, the Cruiser! These are able to travel outside of our solar system thanks to the recent developments in Hyperspace technology, and can carry our current ships in their holds.
|
||||
7 en Civilian Transportation Act This law grants our citizens the right to use military ships to move between planets. This increases happiness but reduces battle efficiency of our ships since they have civilians on board.
|
||||
8 en Room Temperature Superconductors Sir! Our scientists have worked on a new type of electronic circuitry that will allow us to greatly improve the efficiency of our factories, using those room temperature superconductors.
|
||||
9 en Nanotechnologies Sir! Our scientists have made major progress in miniaturisation. With this technology our researchers have gained the capability to work at the "nano" level.
|
||||
10 en Advanced Hospitals Sir! We have successfully researched a new public service! We hope that these "Advanced Hospitals" will improve the health of our subjects so that they are less likely to bite the dust at an unprofitable moment.
|
||||
11 en High-efficiency Hydroponics Recent progress in bio-engineering has allowed for new farming techniques, that are safer for the planet and allow for further studies in green technologies.
|
||||
12 en Safe Recreational Drugs Recent progress in the field of farming has allowed our scientists to develop safe recreational drugs such as the so-called "Space weed". This will improve commerce and make the population happier, since these drugs can be used instead of traditional anaesthetics in our hospitals.
|
||||
13 en Legalize Space Weed Yeah, maaan ... I mean, Sir ... Enacting this law will allow every citizen in our empire to smoke Space Weed as they see fit, without any harmful effect for their health. I mean... huh, What was I saying again? ... Ah, yes! Well, they might be a bit inefficient, because they'll still be stoned, but they''ll be happy!
|
||||
14 en Cloning Techniques Sir! Their stem cells analysis have finally brought our scientists a new breakthrough. Our researchers have succeeded in cloning various lifeforms.
|
||||
15 en Nano-scale Computers Sir, their recent progresses in nanotechnologies has allowed our scientists to create a new generation of computers. This new miniaturised computer allows us to improve research efficiency and opens a brand new field of research.
|
||||
16 en Quantum Gravitation These advances in the field of quantum theory will open a new area for further studies.
|
||||
17 en Miniaturised Particle Colliders These new and small particle colliders increase research in many areas, increasing lab outputs.
|
||||
18 en Advanced Communications Having achieved major breakthroughs in electronic research, our scientists are now able to apply this research to the communications field, where some interesting developments are expected.
|
||||
20 en Quantum Computers Based on the new discoveries in the quantum theory field, these new computers are much more efficient and faster. Equipping our labs will be expensive but the advantages of the increased research speed should be incredible.
|
||||
21 en Economy Globalisation Recent advances in both communications and computer capacities have allowed us to set up an empire wide economic system that should increase our planets base income.
|
||||
22 en Hyperspace Theory Our scientists have developed and tested a complete advanced theory regarding the structure of Hyperspace! We need to upgrade their labs for them to continue researches in this field.
|
||||
23 en Increased Research Grants This law allows to divert a higher percentage of income towards research thus allowing faster discoveries but reducing income.
|
||||
24 en Hardened Alloys These new improved alloys are more resistant and will allow for less losses in battle as well as future advances in industry research.
|
||||
25 en Experimental Anti-Matter Production Recent advances in new alloy production and a better knowledge of quantum theory have allowed our scientists to produce anti-matter for the first time. Research should be continued in this area since the applications could be tremendous.
|
||||
26 en Nanofiber Armor Sir! Applying nanotechnologies to the military field our scientists have managed to produce nano-fiber armors for our ground troups. Since our soldiers will be better protected against rioters we'll need to send less of them on the ground to take control of a planet.
|
||||
27 en Lifeform Engineering Our scientists have devised a method to design lifeforms from scratch! Although this breakthrough has no direct application, further research should be funded, the potential gains are tremendous!
|
||||
28 en Sentient Lifeform Engineering Sir! Our biologists have finally managed to create intelligent lifeforms from scratch, thus opening a brand new field of studies.
|
||||
29 en Cloning Vats Our scientists have perfected their cloning techniques, allowing them to grow real clones in vats. Our industrial production could be greatly improved using this technology!
|
||||
30 en Nourishment Purification Sir! We have successfully researched a new way to improve food, Nourishment purification! This process will give our subjects a healthier lifespan by removing all the nasties in their food.
|
||||
31 en Green Production These new production methods are safer for planetary ecology, making the population happier but slightly reducing factory productivity.
|
||||
32 en Biosphere Protection Pact Enforcing this law forces the industrial sector to use greener production methods that make the population happier but reduce productivity.
|
||||
33 en Corpse Reanimation Sir! Our scientists have established a new technology, Corpse Reanimation! This technology will mean about 60% of our subjects will be able to be brought back to life after death through the use of modified cloning vats. This should lead to a decrease in total death and an increase in workers for our factories.
|
||||
34 en Forced Human Cloning Sir! We could enact a law that would allow our government to clone citizens and boost our population growth! Our people wouldn't be too happy about it though...
|
||||
35 en Arcologies Sir! We are now able to build arcologies, which will allow us to house loads more citizens on our empire's planets!
|
||||
36 en Robotics Recent advances in electronics and new materials have allowed our engineers to design autonomous robots that will help our workers and improve the production of our factories.
|
||||
37 en Adaptive Materials New developments in research have allowed our scientists to create materials that adapt to the needs of our civilians, thus providing even more resistent alloys.
|
||||
38 en Cybernetic Interfaces Sir! Our scientists have found a way to interface the human brain with a machine. This new technology allows a direct interface between electronic and biological systems, making our ships more reactive to their pilots' commands.
|
||||
39 en Exoskeleton Sir! Our scientists have managed to improve even further the equipment of our ground troups. With those new exoskeletons we will require to send even less GA ships to get the inhabitants of another planet to share our views..
|
||||
40 en Temporal Mechanics The progress of our scientists has enabled us to better understand temporal phenomenons, which should allow for a wide range of new discoveries. Further funding of this area of study is a necessity.
|
||||
41 en Space-time folding Sir! Our scientists have pushed the limit of Hyperspace theory! This will allow us to design better, faster ship engines and further advances are to be expected! However, upgrading our fleets as well as our laboratories might be a bit expensive...
|
||||
42 en Biological Computers Our scientists have found a way to integrate intelligent lifeforms into our computers, thus improving calculation capabilities. Upgrading our computers, though expensive, should allow our current research projects to reach completion faster.
|
||||
43 en Science Golden Age Enacting this law permits us to divert more resources towards research at the expense of other necessities.
|
||||
44 en Wide Band Jamming This basic jamming technology allows us to try and prevent the planets we attack from transmitting data to their allies. Therefore defensive procedures can potentially be disrupted.
|
||||
45 en Fast Burst Transmission This new technology renders our stellar and interstellar communications less prone to jamming and interception.
|
||||
46 en Hyperspace Beacon Placed in hyperspace around our planets this beacon provides an "anchor" for your ships and those of your alliance, thus reducing the losses in fleet stationed in hyperspace.
|
||||
48 en Quantum Encryption Quantum computers have allowed tremendous progress in encryption algorithms. We can now be more efficient in preventing the enemy from disrupting our communications.
|
||||
49 en Entropy Generator By applying hyperspace theory to telecommunications we've found a new way to disrupt enemy communications, making it even harder for them to transmit accurate data to their allies.
|
||||
50 en Surgical Robots This technology provides new advances in the medical field, allowing for further researches in this area. Further funding should bring quite interesting breakthroughs.
|
||||
51 en Medical Bays Our engineers have modified the designs for our capital ships in order to include highly advanced medical bays, in which the pilots can be healed when they are wounded in combat. This improvement will reduce our losses, but our fleets and factories must be upgraded first.
|
||||
52 en Resurrection tanks Our engineers have updated the designs for our capital ships. The medical bays will now integrate the equipment required to raise our pilots from the dead, further reducing battle losses.
|
||||
53 en Self-healing Materials Sir! Our scientists have have found a way to grow advanced, self-healing materials. This new technology will allow us to provide regeneration and auto-repair capabilities to both our ships and factories. We will thus greatly reduce our losses in battle and gain productivity in our industrial sector.
|
||||
54 en Self-repairing Exoskeleton Sir! Incorporating the newest alloys to our soldiers exoskeletons, our scientists have set up self-repairing exoskeletons. Even more efficient against attacking crowds, this new armor generation will reduce even more the number of GA ships required to take control of a foreign planet.
|
||||
55 en Biological Drones This technology allows industry to use specifically designed lifeforms to replace workers in the factories. These lifeforms will be much more efficient than human beings, but our citizens might not like getting sacked in favour of their new replacements.
|
||||
56 en Ban Biological Drones To fight the decrease in happiness caused by biological drones, we can enact a law that bans their presence in our empire. This law counters all effects of biological drones and restores factories to their previous level of productivity.
|
||||
57 en Force fields Our scientists have found a way to create force fields. The direct military application is the addition of shields to our current fleets, which will reduce losses.
|
||||
58 en Lifeform Energy Manipulation Sir! Our scientists have managed to engineer lifeforms capabable of manipulating energy. This new discovery lets us foresee some astonishing future breakthroughs.
|
||||
59 en Civilian Communication Act Passing this law will permit civilians access to our militaries' advanced communication networks. Civilians will be happier since they can keep in touch with friends, but this civilian use of military installations could disrupt anti-jamming and jamming systems!
|
||||
61 en Automated Turrets Sir! Including robotics in our turrets will improve their accuracy and firing efficiency. With these new turrets we will be able to better defend our planets.
|
||||
62 en Interstellar University Sir! Thanks to our recent improvements in communications and computing capacities we've brought education to a new scale. Our interstellar universities will allow us to better adapt education programs to students'' needs and to improve cooperation between our research labs.
|
||||
63 en Battle Cruisers Sir! We have successfully researched a new type of ship, the Battle Cruiser! These ships are an improvement on our Cruisers as they are faster and more deadly. However, they are considerably more expensive to build and carry less of our system ships.
|
||||
64 en Phase Neutraliser Applying temporal mechanics to communications, our scientists have managed to find better ways to disrupt enemy data flows, thus reducing their chances of accurate data being sent to their allies.
|
||||
65 en Multiphasic Transmission Applying temporal mechanics to communication, our scientists have managed to use it to transmit data in fluctuating phases. This further protects our communications from enemy jamming technologies.
|
||||
68 en Sensor Turrets Sire dude! Equipping our turrets with sensors designed out of our probe technology, we can gain in the accuracy of our aiming, thus becoming more efficient.
|
||||
69 en Global Defense Bill This new law goes even further than the Martial Law to cope with the military's will. But our citizens will even less appreciate it.
|
||||
70 en Wormhole Theory Going even further than space-time folding, our scientists have written a theory that, when put into practice, would allow us to manipulate wormholes. Of course further studies are required to reach any real application.
|
||||
71 en Biological Propulsion Systems Sir! Our scientists have found a way to create and grow artificial lifeforms capable of basic space flight. These can be used to replace our most simple ships in order to gain efficiency.
|
||||
72 en Mass Anti-matter Production Using newly acquired technologies our scientists have acheived mass production of anti-matter thus opening a brand new field of applications.
|
||||
73 en Singularity Housing Using the principles of Space-time folding, our engineers have improved our arcology design. Hyperspace and force-field generators must be integrated into our existing arcologies in order to allow our planets to house even more citizens.
|
||||
74 en Intelligent Materials Bringing sentience to the materials they use, our scientists provide us with wonderful new ways of building stuff.
|
||||
75 en Automated Factories Sir! Using sentient materials in our factories will allow us to gain production efficiency.
|
||||
76 en Wild Capitalism This law allows the industrial sector to use any means necessary to increase profit. As a consequence, base planetary income and industrial factory benefits are increased but military factories, research and happiness suffer from it.
|
||||
77 en Adaptive Plating Sir! Our scientists have come up with a new way to reduce battle damage. They have integrated intelligent materials in our ships' plating thus offering them better defensive abilities.
|
||||
78 en Anti-matter Generators Sir! Our scientists have designed a new way to produce energy. Equipping our factories with these anti-matter generators will improve our productivity.
|
||||
79 en Biological Subspace Control Sir! Our scientists have engineered some new astonishing lifeforms. These artificial creatures are capable of controlling subspace fields. This major discovery opens a new era for our future studies.
|
||||
80 en Wormhole Collapsing Sir, our scientists have devised a new defence. This technology allows our planets to build counter-measures that will allow them to prevent unwanted hyperspace windows from forming in orbit. This should prevent 10% of an enemy fleet from exiting hyperspace above the planet and delay them in hyperspace for 1 more hour.
|
||||
81 en Wormholes This technology applies space-time folding principles to spacebats, allowing your citizens to move freely between the planets in your empire. They will now be living in ecstacy as they will be able to visit their families, friends and dolphins.
|
||||
82 en Subspace Data conduit Applying wormhole theory to communications has allowed our scientists to create subspace conduits to transmit data, thus hiding it even better from enemy disruption techniques.
|
||||
83 en Self-sustained Arcologies Sir! By combining their expertise in hyperspace theory and biological engineering, our scientists have found a way to create "grown" housing that will provide room and nourishment for our citizens. This will allow us to sustain more people on our planets.
|
||||
84 en Matter Anti-matter Engines Sir! Our scientists have found a new application for matter anti-matter reactions: propulsion systems! This new line of engines should increase our ships efficiency greatly.
|
||||
85 en Biological Turrets Building our turrets with intelligent materials should allow us to take advantage of their sentience to gain in accuracy and fire power.
|
||||
86 en Localised Wormhole Destabilisation Applying wormhole collapsing technologies in a localised way allows us to disrupt subspace data conduits and other long range communication, rending them less efficient.
|
||||
87 en Wormhole Lockdown This law prevents your citizens from using the planetary gateways, cancelling the effects of the wormhole technology.
|
||||
88 en Wormhole Super Nova Sir! With this technology we can initiate a chain reaction on a planetary wormhole that will cause it to flare up and destroy anything in the vicinity, including the planet and scaring the living hell out of the planet's neighbours.
|
||||
89 en Biological Hyperspace Engines Sir! Our scientists have found a way to grow and nurture organic hyperspace engines. We will now be able to grow living capital ships, improving our fleets' efficiency.
|
||||
90 en Matter Anti-matter Missiles Using matter / anti-matter reactions in our warheads should greatly increase the damage caused by our ships.
|
||||
\.
|
801
sql/beta5/data/standard.sql
Normal file
801
sql/beta5/data/standard.sql
Normal file
|
@ -0,0 +1,801 @@
|
|||
-- LegacyWorlds Beta 5
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- beta5/data/readonly.sql
|
||||
--
|
||||
-- Beta 5 games:
|
||||
-- Read-only data insertion
|
||||
--
|
||||
-- Copyright(C) 2004-2007, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
-- ECM probability table
|
||||
COPY ecm FROM STDIN;
|
||||
0 1 0
|
||||
0 2 0
|
||||
0 3 0
|
||||
0 4 1
|
||||
0 5 99
|
||||
1 1 0
|
||||
1 2 0
|
||||
1 3 10
|
||||
1 4 70
|
||||
1 5 20
|
||||
2 1 0
|
||||
2 2 10
|
||||
2 3 70
|
||||
2 4 15
|
||||
2 5 5
|
||||
3 1 5
|
||||
3 2 70
|
||||
3 3 15
|
||||
3 4 8
|
||||
3 5 2
|
||||
4 1 60
|
||||
4 2 30
|
||||
4 3 6
|
||||
4 4 4
|
||||
4 5 0
|
||||
\.
|
||||
|
||||
-- ECCM probability table
|
||||
COPY eccm FROM STDIN;
|
||||
0 0 99
|
||||
0 1 1
|
||||
0 2 0
|
||||
0 3 0
|
||||
0 4 0
|
||||
1 0 20
|
||||
1 1 70
|
||||
1 2 10
|
||||
1 3 0
|
||||
1 4 0
|
||||
2 0 10
|
||||
2 1 20
|
||||
2 2 60
|
||||
2 3 10
|
||||
2 4 0
|
||||
3 0 5
|
||||
3 1 10
|
||||
3 2 20
|
||||
3 3 60
|
||||
3 4 5
|
||||
4 0 0
|
||||
4 1 5
|
||||
4 2 10
|
||||
4 3 40
|
||||
4 4 45
|
||||
\.
|
||||
|
||||
|
||||
-- Default rules
|
||||
COPY rule_def FROM stdin;
|
||||
military_level 0
|
||||
pop_growth_factor 1
|
||||
if_productivity 30
|
||||
if_productivity_factor 10
|
||||
base_income 2
|
||||
factory_cost 10
|
||||
turret_cost 20
|
||||
mf_productivity 10
|
||||
mf_productivity_factor 10
|
||||
workunits_turret 1500
|
||||
workunits_gaship 4500
|
||||
workunits_fighter 2000
|
||||
workunits_cruiser 20000
|
||||
workunits_bcruiser 22000
|
||||
build_cost_turret 400
|
||||
build_cost_gaship 750
|
||||
build_cost_fighter 500
|
||||
build_cost_cruiser 5000
|
||||
build_cost_bcruiser 15000
|
||||
if_cost 400
|
||||
mf_cost 400
|
||||
battle_losses 100
|
||||
unhappiness_factor 100
|
||||
effective_fleet_power 100
|
||||
planet_max_pop 10000
|
||||
capital_ship_speed 1
|
||||
prevent_hs_exit 0
|
||||
planet_destruction 0
|
||||
turret_power 10
|
||||
gaship_power 5
|
||||
fighter_power 10
|
||||
cruiser_power 40
|
||||
bcruiser_power 80
|
||||
gaship_upkeep 40
|
||||
fighter_upkeep 50
|
||||
cruiser_upkeep 500
|
||||
bcruiser_upkeep 1500
|
||||
research_percent 200
|
||||
gaship_space 3
|
||||
fighter_space 1
|
||||
cruiser_haul 20
|
||||
bcruiser_haul 15
|
||||
ecm_level 0
|
||||
eccm_level 0
|
||||
gaship_pop 200
|
||||
hs_beacon_level 0
|
||||
probe_tech 0
|
||||
\.
|
||||
|
||||
|
||||
-- Rule handlers
|
||||
COPY rule_handler FROM STDIN;
|
||||
unhappiness_factor UpdateHappiness
|
||||
planet_max_pop UpdateMaxPopulation
|
||||
effective_fleet_power UpdateFleetPower
|
||||
gaship_power UpdateFleetPower
|
||||
fighter_power UpdateFleetPower
|
||||
cruiser_power UpdateFleetPower
|
||||
bcruiser_power UpdateFleetPower
|
||||
ecm_level UpdateCommTech
|
||||
eccm_level UpdateCommTech
|
||||
\.
|
||||
|
||||
|
||||
-- Research definitions
|
||||
COPY research FROM STDIN;
|
||||
1 7000 50000 0 1 FALSE
|
||||
2 5000 15000 0 0 FALSE
|
||||
3 4000 20000 0 2 FALSE
|
||||
4 6000 30000 0 2 FALSE
|
||||
5 13333 5000 0 1 TRUE
|
||||
6 29000 300000 0 1 FALSE
|
||||
7 44667 50000 0 2 TRUE
|
||||
8 10333 40000 0 2 FALSE
|
||||
9 10333 40000 0 2 FALSE
|
||||
10 18000 50000 0 2 FALSE
|
||||
11 18000 50000 0 0 FALSE
|
||||
12 38000 80000 2 2 FALSE
|
||||
13 57667 15000 1 2 TRUE
|
||||
14 54000 100000 1 0 FALSE
|
||||
15 37554 100000 1 2 FALSE
|
||||
16 14667 100000 0 0 FALSE
|
||||
17 34889 100000 1 0 FALSE
|
||||
18 21777 150000 1 0 FALSE
|
||||
20 99628 500000 1 2 FALSE
|
||||
21 211873 1000000 2 2 FALSE
|
||||
22 99628 500000 1 0 FALSE
|
||||
23 51519 30000 1 0 TRUE
|
||||
24 28777 100000 1 2 FALSE
|
||||
25 87925 500000 1 0 FALSE
|
||||
26 23777 100000 2 1 FALSE
|
||||
27 135777 500000 1 0 FALSE
|
||||
28 241036 800000 1 0 FALSE
|
||||
29 112000 200000 1 2 FALSE
|
||||
30 68000 1500000 2 2 FALSE
|
||||
31 44000 400000 1 2 FALSE
|
||||
32 68667 60000 1 2 TRUE
|
||||
33 300000 400000 2 2 FALSE
|
||||
34 174333 80000 1 2 TRUE
|
||||
35 127036 800000 2 2 FALSE
|
||||
36 72146 600000 1 2 FALSE
|
||||
37 68369 300000 1 2 FALSE
|
||||
38 98072 500000 1 1 FALSE
|
||||
39 212466 700000 2 1 FALSE
|
||||
40 172837 1000000 1 0 FALSE
|
||||
41 280449 2000000 1 0 FALSE
|
||||
42 554218 1500000 1 2 FALSE
|
||||
43 860476 100000 1 0 TRUE
|
||||
44 49036 500000 2 1 FALSE
|
||||
45 49036 500000 1 1 FALSE
|
||||
46 112048 1000000 2 1 FALSE
|
||||
48 238218 1500000 1 1 FALSE
|
||||
49 238218 1500000 1 1 FALSE
|
||||
50 160195 800000 1 2 FALSE
|
||||
51 302260 1500000 2 1 FALSE
|
||||
52 875013 3000000 2 1 FALSE
|
||||
53 342195 1500000 1 0 FALSE
|
||||
54 839548 2000000 1 1 FALSE
|
||||
55 517576 2000000 1 2 FALSE
|
||||
56 740101 70000 1 2 TRUE
|
||||
57 263996 1500000 1 0 FALSE
|
||||
58 241036 1500000 1 0 FALSE
|
||||
59 403005 120000 1 2 TRUE
|
||||
60 307222 3000000 2 1 FALSE
|
||||
61 136195 500000 1 1 FALSE
|
||||
62 1106581 2500000 1 2 FALSE
|
||||
63 583758 2500000 1 1 FALSE
|
||||
64 628073 5000000 1 1 FALSE
|
||||
65 628073 5000000 1 1 FALSE
|
||||
68 319418 2000000 1 1 FALSE
|
||||
69 1019937 150000 1 1 TRUE
|
||||
70 1949373 5000000 1 0 FALSE
|
||||
71 630811 4000000 2 1 FALSE
|
||||
72 529228 2500000 2 0 FALSE
|
||||
73 965308 3800000 1 2 FALSE
|
||||
74 1295217 4000000 1 2 FALSE
|
||||
75 2537057 7000000 1 2 FALSE
|
||||
76 3725240 200000 1 2 TRUE
|
||||
77 2228337 10000000 1 1 FALSE
|
||||
78 1251897 4000000 1 2 FALSE
|
||||
79 845313 4000000 1 0 FALSE
|
||||
80 2719164 10000000 1 1 FALSE
|
||||
81 2709164 10000000 1 2 FALSE
|
||||
82 3616595 12000000 1 1 FALSE
|
||||
83 4321117 10000000 1 2 FALSE
|
||||
84 805637 5000000 1 1 FALSE
|
||||
85 2088549 8000000 1 1 FALSE
|
||||
86 4642983 12000000 1 1 FALSE
|
||||
87 3642219 170000 1 2 TRUE
|
||||
88 7457771 15000000 1 1 FALSE
|
||||
89 4000692 10000000 1 1 FALSE
|
||||
90 2627540 10000000 1 1 FALSE
|
||||
\.
|
||||
|
||||
|
||||
-- Research dependencies
|
||||
COPY research_dep FROM STDIN;
|
||||
5 1
|
||||
6 1
|
||||
6 2
|
||||
16 2
|
||||
46 2
|
||||
8 3
|
||||
9 3
|
||||
17 3
|
||||
10 4
|
||||
11 4
|
||||
38 4
|
||||
7 6
|
||||
51 6
|
||||
63 6
|
||||
71 6
|
||||
15 8
|
||||
18 8
|
||||
36 8
|
||||
15 9
|
||||
24 9
|
||||
26 9
|
||||
27 9
|
||||
14 10
|
||||
30 10
|
||||
50 10
|
||||
12 11
|
||||
30 11
|
||||
31 11
|
||||
13 12
|
||||
27 14
|
||||
29 14
|
||||
20 15
|
||||
22 15
|
||||
38 15
|
||||
17 16
|
||||
20 16
|
||||
22 16
|
||||
25 16
|
||||
23 17
|
||||
43 17
|
||||
21 18
|
||||
44 18
|
||||
45 18
|
||||
68 46
|
||||
21 20
|
||||
42 20
|
||||
48 20
|
||||
76 21
|
||||
40 22
|
||||
49 22
|
||||
57 22
|
||||
25 24
|
||||
35 24
|
||||
36 24
|
||||
37 24
|
||||
72 25
|
||||
39 26
|
||||
28 27
|
||||
53 27
|
||||
58 27
|
||||
42 28
|
||||
55 28
|
||||
33 29
|
||||
34 29
|
||||
33 30
|
||||
32 31
|
||||
35 31
|
||||
52 33
|
||||
73 35
|
||||
50 36
|
||||
55 36
|
||||
61 36
|
||||
53 37
|
||||
57 37
|
||||
63 37
|
||||
39 38
|
||||
71 38
|
||||
54 39
|
||||
41 40
|
||||
64 40
|
||||
65 40
|
||||
63 41
|
||||
70 41
|
||||
73 41
|
||||
79 41
|
||||
43 42
|
||||
62 42
|
||||
74 42
|
||||
49 44
|
||||
59 44
|
||||
46 45
|
||||
48 45
|
||||
59 48
|
||||
62 48
|
||||
65 48
|
||||
64 49
|
||||
51 50
|
||||
52 51
|
||||
54 53
|
||||
74 53
|
||||
78 53
|
||||
56 55
|
||||
75 55
|
||||
72 57
|
||||
73 57
|
||||
71 58
|
||||
77 58
|
||||
79 58
|
||||
68 61
|
||||
69 61
|
||||
85 61
|
||||
70 62
|
||||
69 63
|
||||
89 63
|
||||
90 63
|
||||
86 64
|
||||
82 65
|
||||
80 70
|
||||
81 70
|
||||
82 70
|
||||
89 71
|
||||
78 72
|
||||
84 72
|
||||
83 73
|
||||
75 74
|
||||
77 74
|
||||
83 74
|
||||
85 74
|
||||
76 75
|
||||
90 78
|
||||
83 79
|
||||
89 79
|
||||
86 80
|
||||
88 80
|
||||
87 81
|
||||
88 81
|
||||
89 84
|
||||
60 46
|
||||
60 22
|
||||
\.
|
||||
|
||||
|
||||
-- Research effects
|
||||
COPY research_effect FROM STDIN;
|
||||
1 military_level 1
|
||||
3 battle_losses -2
|
||||
4 if_cost 80
|
||||
4 if_productivity_factor 2
|
||||
5 if_productivity_factor -2
|
||||
5 mf_productivity_factor 3
|
||||
5 unhappiness_factor 5
|
||||
6 military_level 1
|
||||
7 effective_fleet_power -5
|
||||
7 unhappiness_factor -4
|
||||
8 if_cost 40
|
||||
8 if_productivity_factor 1
|
||||
8 mf_cost 40
|
||||
8 mf_productivity_factor 1
|
||||
9 if_cost 40
|
||||
9 if_productivity_factor 1
|
||||
9 mf_cost 40
|
||||
9 mf_productivity_factor 1
|
||||
10 pop_growth_factor 1
|
||||
12 unhappiness_factor -1
|
||||
13 if_productivity_factor -2
|
||||
13 mf_productivity_factor -3
|
||||
13 unhappiness_factor -5
|
||||
15 research_percent 10
|
||||
17 research_percent 10
|
||||
18 unhappiness_factor -2
|
||||
20 research_percent 10
|
||||
21 base_income 2
|
||||
23 base_income -1
|
||||
23 if_productivity_factor -2
|
||||
23 research_percent 25
|
||||
24 battle_losses -5
|
||||
24 if_cost 80
|
||||
24 if_productivity_factor 2
|
||||
24 mf_cost 80
|
||||
24 mf_productivity_factor 2
|
||||
26 gaship_pop 75
|
||||
29 if_cost 120
|
||||
29 if_productivity_factor 3
|
||||
30 pop_growth_factor 1
|
||||
31 if_productivity_factor -1
|
||||
31 mf_productivity_factor -1
|
||||
31 unhappiness_factor -2
|
||||
32 if_productivity_factor -1
|
||||
32 mf_productivity_factor -1
|
||||
32 unhappiness_factor -4
|
||||
33 pop_growth_factor 1
|
||||
34 pop_growth_factor 1
|
||||
34 unhappiness_factor 5
|
||||
35 planet_max_pop 10000
|
||||
36 if_cost 120
|
||||
36 if_productivity_factor 3
|
||||
36 mf_cost 120
|
||||
36 mf_productivity_factor 3
|
||||
37 battle_losses -5
|
||||
37 if_cost 80
|
||||
37 if_productivity_factor 2
|
||||
37 mf_cost 80
|
||||
37 mf_productivity_factor 2
|
||||
38 effective_fleet_power 10
|
||||
39 gaship_pop 75
|
||||
41 capital_ship_speed 1
|
||||
42 research_percent 10
|
||||
43 if_productivity_factor -3
|
||||
43 mf_productivity_factor -3
|
||||
43 research_percent 50
|
||||
44 ecm_level 1
|
||||
45 eccm_level 1
|
||||
46 hs_beacon_level 1
|
||||
48 eccm_level 1
|
||||
49 ecm_level 1
|
||||
51 battle_losses -2
|
||||
52 battle_losses -2
|
||||
53 battle_losses -2
|
||||
53 if_cost 80
|
||||
53 if_productivity_factor 2
|
||||
53 mf_cost 80
|
||||
53 mf_productivity_factor 2
|
||||
54 gaship_pop 75
|
||||
55 if_cost 80
|
||||
55 if_productivity_factor 2
|
||||
55 mf_cost 80
|
||||
55 mf_productivity_factor 2
|
||||
55 unhappiness_factor 7
|
||||
56 if_productivity_factor -2
|
||||
56 mf_productivity_factor -2
|
||||
56 unhappiness_factor -7
|
||||
57 battle_losses -4
|
||||
59 eccm_level -1
|
||||
59 ecm_level -1
|
||||
59 unhappiness_factor -4
|
||||
60 hs_beacon_level 1
|
||||
61 turret_power 3
|
||||
62 research_percent 10
|
||||
63 military_level 1
|
||||
64 ecm_level 1
|
||||
65 eccm_level 1
|
||||
68 turret_power 3
|
||||
69 if_productivity_factor -4
|
||||
69 mf_productivity_factor 6
|
||||
69 unhappiness_factor 10
|
||||
70 capital_ship_speed 1
|
||||
71 fighter_power 4
|
||||
71 gaship_power 2
|
||||
73 planet_max_pop 10000
|
||||
74 battle_losses -2
|
||||
74 if_cost 80
|
||||
74 if_productivity_factor 2
|
||||
74 mf_cost 80
|
||||
74 mf_productivity_factor 2
|
||||
75 if_cost 160
|
||||
75 if_productivity_factor 4
|
||||
75 mf_cost 120
|
||||
75 mf_productivity_factor 3
|
||||
76 base_income 3
|
||||
76 if_productivity_factor 10
|
||||
76 mf_productivity_factor -5
|
||||
76 research_percent -50
|
||||
76 unhappiness_factor 15
|
||||
77 battle_losses -5
|
||||
78 if_cost 80
|
||||
78 if_productivity_factor 2
|
||||
78 mf_cost 80
|
||||
78 mf_productivity_factor 2
|
||||
80 prevent_hs_exit 1
|
||||
81 if_productivity_factor -3
|
||||
81 unhappiness_factor -5
|
||||
82 eccm_level 1
|
||||
83 planet_max_pop 10000
|
||||
84 capital_ship_speed 1
|
||||
84 effective_fleet_power 5
|
||||
85 turret_power 3
|
||||
86 ecm_level 1
|
||||
87 if_cost 120
|
||||
87 if_productivity_factor 3
|
||||
87 unhappiness_factor 7
|
||||
88 planet_destruction 1
|
||||
89 bcruiser_power 20
|
||||
89 cruiser_power 10
|
||||
90 effective_fleet_power 10
|
||||
\.
|
||||
|
||||
|
||||
-- Research descriptions
|
||||
COPY research_txt FROM STDIN;
|
||||
1 en Fighters Sir! We have successfully researched a new type of ship, the Fighter! These ships are faster and more efficient at combating enemy ships than our current Ground Assault ships.
|
||||
2 en Hyperspace Basics Sir! Our scientists have made major progress in understanding the basics behind Hyperspace theory. Those basic hyperspace capabilities are the very beginning of a new area in space flight and allow a wide range of new experiments.
|
||||
3 en Advanced Materials Sir! Our scientists just discovered new production methods that will allow us to create hardened materials! Our factories must be upgraded in order to start producing those new alloys.
|
||||
4 en Bio-engineering Sir! Our scientists worked hard to improve our empire's knowledge of bio-engineering, which will greatly improve the production of basic goods, as well as pave the way for further advances.
|
||||
5 en Martial law Sir! We can enact Martial Law to force our people to work in the military's best interest! They probably won''t be too happy about it, and our economy might suffer, but who cares? Our military production will be greatly improved!
|
||||
6 en Cruisers Sir! We have successfully researched a new type of ship, the Cruiser! These are able to travel outside of our solar system thanks to the recent developments in Hyperspace technology, and can carry our current ships in their holds.
|
||||
7 en Civilian Transportation Act This law grants our citizens the right to use military ships to move between planets. This increases happiness but reduces battle efficiency of our ships since they have civilians on board.
|
||||
8 en Room Temperature Superconductors Sir! Our scientists have worked on a new type of electronic circuitry that will allow us to greatly improve the efficiency of our factories, using those room temperature superconductors.
|
||||
9 en Nanotechnologies Sir! Our scientists have made major progress in miniaturisation. With this technology our researchers have gained the capability to work at the "nano" level.
|
||||
10 en Advanced Hospitals Sir! We have successfully researched a new public service! We hope that these "Advanced Hospitals" will improve the health of our subjects so that they are less likely to bite the dust at an unprofitable moment.
|
||||
11 en High-efficiency Hydroponics Recent progress in bio-engineering has allowed for new farming techniques, that are safer for the planet and allow for further studies in green technologies.
|
||||
12 en Safe Recreational Drugs Recent progress in the field of farming has allowed our scientists to develop safe recreational drugs such as the so-called "Space weed". This will improve commerce and make the population happier, since these drugs can be used instead of traditional anaesthetics in our hospitals.
|
||||
13 en Legalize Space Weed Yeah, maaan ... I mean, Sir ... Enacting this law will allow every citizen in our empire to smoke Space Weed as they see fit, without any harmful effect for their health. I mean... huh, What was I saying again? ... Ah, yes! Well, they might be a bit inefficient, because they'll still be stoned, but they''ll be happy!
|
||||
14 en Cloning Techniques Sir! Their stem cells analysis have finally brought our scientists a new breakthrough. Our researchers have succeeded in cloning various lifeforms.
|
||||
15 en Nano-scale Computers Sir, their recent progresses in nanotechnologies has allowed our scientists to create a new generation of computers. This new miniaturised computer allows us to improve research efficiency and opens a brand new field of research.
|
||||
16 en Quantum Gravitation These advances in the field of quantum theory will open a new area for further studies.
|
||||
17 en Miniaturised Particle Colliders These new and small particle colliders increase research in many areas, increasing lab outputs.
|
||||
18 en Advanced Communications Having achieved major breakthroughs in electronic research, our scientists are now able to apply this research to the communications field, where some interesting developments are expected.
|
||||
20 en Quantum Computers Based on the new discoveries in the quantum theory field, these new computers are much more efficient and faster. Equipping our labs will be expensive but the advantages of the increased research speed should be incredible.
|
||||
21 en Economy Globalisation Recent advances in both communications and computer capacities have allowed us to set up an empire wide economic system that should increase our planets base income.
|
||||
22 en Hyperspace Theory Our scientists have developed and tested a complete advanced theory regarding the structure of Hyperspace! We need to upgrade their labs for them to continue researches in this field.
|
||||
23 en Increased Research Grants This law allows to divert a higher percentage of income towards research thus allowing faster discoveries but reducing income.
|
||||
24 en Hardened Alloys These new improved alloys are more resistant and will allow for less losses in battle as well as future advances in industry research.
|
||||
25 en Experimental Anti-Matter Production Recent advances in new alloy production and a better knowledge of quantum theory have allowed our scientists to produce anti-matter for the first time. Research should be continued in this area since the applications could be tremendous.
|
||||
26 en Nanofiber Armor Sir! Applying nanotechnologies to the military field our scientists have managed to produce nano-fiber armors for our ground troups. Since our soldiers will be better protected against rioters we'll need to send less of them on the ground to take control of a planet.
|
||||
27 en Lifeform Engineering Our scientists have devised a method to design lifeforms from scratch! Although this breakthrough has no direct application, further research should be funded, the potential gains are tremendous!
|
||||
28 en Sentient Lifeform Engineering Sir! Our biologists have finally managed to create intelligent lifeforms from scratch, thus opening a brand new field of studies.
|
||||
29 en Cloning Vats Our scientists have perfected their cloning techniques, allowing them to grow real clones in vats. Our industrial production could be greatly improved using this technology!
|
||||
30 en Nourishment Purification Sir! We have successfully researched a new way to improve food, Nourishment purification! This process will give our subjects a healthier lifespan by removing all the nasties in their food.
|
||||
31 en Green Production These new production methods are safer for planetary ecology, making the population happier but slightly reducing factory productivity.
|
||||
32 en Biosphere Protection Pact Enforcing this law forces the industrial sector to use greener production methods that make the population happier but reduce productivity.
|
||||
33 en Corpse Reanimation Sir! Our scientists have established a new technology, Corpse Reanimation! This technology will mean about 60% of our subjects will be able to be brought back to life after death through the use of modified cloning vats. This should lead to a decrease in total death and an increase in workers for our factories.
|
||||
34 en Forced Human Cloning Sir! We could enact a law that would allow our government to clone citizens and boost our population growth! Our people wouldn't be too happy about it though...
|
||||
35 en Arcologies Sir! We are now able to build arcologies, which will allow us to house loads more citizens on our empire's planets!
|
||||
36 en Robotics Recent advances in electronics and new materials have allowed our engineers to design autonomous robots that will help our workers and improve the production of our factories.
|
||||
37 en Adaptive Materials New developments in research have allowed our scientists to create materials that adapt to the needs of our civilians, thus providing even more resistent alloys.
|
||||
38 en Cybernetic Interfaces Sir! Our scientists have found a way to interface the human brain with a machine. This new technology allows a direct interface between electronic and biological systems, making our ships more reactive to their pilots' commands.
|
||||
39 en Exoskeleton Sir! Our scientists have managed to improve even further the equipment of our ground troups. With those new exoskeletons we will require to send even less GA ships to get the inhabitants of another planet to share our views..
|
||||
40 en Temporal Mechanics The progress of our scientists has enabled us to better understand temporal phenomenons, which should allow for a wide range of new discoveries. Further funding of this area of study is a necessity.
|
||||
41 en Space-time folding Sir! Our scientists have pushed the limit of Hyperspace theory! This will allow us to design better, faster ship engines and further advances are to be expected! However, upgrading our fleets as well as our laboratories might be a bit expensive...
|
||||
42 en Biological Computers Our scientists have found a way to integrate intelligent lifeforms into our computers, thus improving calculation capabilities. Upgrading our computers, though expensive, should allow our current research projects to reach completion faster.
|
||||
43 en Science Golden Age Enacting this law permits us to divert more resources towards research at the expense of other necessities.
|
||||
44 en Wide Band Jamming This basic jamming technology allows us to try and prevent the planets we attack from transmitting data to their allies. Therefore defensive procedures can potentially be disrupted.
|
||||
45 en Fast Burst Transmission This new technology renders our stellar and interstellar communications less prone to jamming and interception.
|
||||
46 en Hyperspace Beacon Placed in hyperspace around our planets this beacon provides an "anchor" for your ships and those of your alliance, thus reducing the losses in fleet stationed in hyperspace.
|
||||
48 en Quantum Encryption Quantum computers have allowed tremendous progress in encryption algorithms. We can now be more efficient in preventing the enemy from disrupting our communications.
|
||||
49 en Entropy Generator By applying hyperspace theory to telecommunications we've found a new way to disrupt enemy communications, making it even harder for them to transmit accurate data to their allies.
|
||||
50 en Surgical Robots This technology provides new advances in the medical field, allowing for further researches in this area. Further funding should bring quite interesting breakthroughs.
|
||||
51 en Medical Bays Our engineers have modified the designs for our capital ships in order to include highly advanced medical bays, in which the pilots can be healed when they are wounded in combat. This improvement will reduce our losses, but our fleets and factories must be upgraded first.
|
||||
52 en Resurrection tanks Our engineers have updated the designs for our capital ships. The medical bays will now integrate the equipment required to raise our pilots from the dead, further reducing battle losses.
|
||||
53 en Self-healing Materials Sir! Our scientists have have found a way to grow advanced, self-healing materials. This new technology will allow us to provide regeneration and auto-repair capabilities to both our ships and factories. We will thus greatly reduce our losses in battle and gain productivity in our industrial sector.
|
||||
54 en Self-repairing Exoskeleton Sir! Incorporating the newest alloys to our soldiers exoskeletons, our scientists have set up self-repairing exoskeletons. Even more efficient against attacking crowds, this new armor generation will reduce even more the number of GA ships required to take control of a foreign planet.
|
||||
55 en Biological Drones This technology allows industry to use specifically designed lifeforms to replace workers in the factories. These lifeforms will be much more efficient than human beings, but our citizens might not like getting sacked in favour of their new replacements.
|
||||
56 en Ban Biological Drones To fight the decrease in happiness caused by biological drones, we can enact a law that bans their presence in our empire. This law counters all effects of biological drones and restores factories to their previous level of productivity.
|
||||
57 en Force fields Our scientists have found a way to create force fields. The direct military application is the addition of shields to our current fleets, which will reduce losses.
|
||||
58 en Lifeform Energy Manipulation Sir! Our scientists have managed to engineer lifeforms capabable of manipulating energy. This new discovery lets us foresee some astonishing future breakthroughs.
|
||||
59 en Civilian Communication Act Passing this law will permit civilians access to our militaries' advanced communication networks. Civilians will be happier since they can keep in touch with friends, but this civilian use of military installations could disrupt anti-jamming and jamming systems!
|
||||
60 en Hyperspace Probing Beacon Adding probing systems to hyperspace beacons, this technology allows for early detection of enemy ships stationed in hyperspace around our planets.
|
||||
61 en Automated Turrets Sir! Including robotics in our turrets will improve their accuracy and firing efficiency. With these new turrets we will be able to better defend our planets.
|
||||
62 en Interstellar University Sir! Thanks to our recent improvements in communications and computing capacities we've brought education to a new scale. Our interstellar universities will allow us to better adapt education programs to students'' needs and to improve cooperation between our research labs.
|
||||
63 en Battle Cruisers Sir! We have successfully researched a new type of ship, the Battle Cruiser! These ships are an improvement on our Cruisers as they are faster and more deadly. However, they are considerably more expensive to build and carry less of our system ships.
|
||||
64 en Phase Neutraliser Applying temporal mechanics to communications, our scientists have managed to find better ways to disrupt enemy data flows, thus reducing their chances of accurate data being sent to their allies.
|
||||
65 en Multiphasic Transmission Applying temporal mechanics to communication, our scientists have managed to use it to transmit data in fluctuating phases. This further protects our communications from enemy jamming technologies.
|
||||
68 en Sensor Turrets Sire dude! Equipping our turrets with sensors designed out of our probe technology, we can gain in the accuracy of our aiming, thus becoming more efficient.
|
||||
69 en Global Defense Bill This new law goes even further than the Martial Law to cope with the military's will. But our citizens will even less appreciate it.
|
||||
70 en Wormhole Theory Going even further than space-time folding, our scientists have written a theory that, when put into practice, would allow us to manipulate wormholes. Of course further studies are required to reach any real application.
|
||||
71 en Biological Propulsion Systems Sir! Our scientists have found a way to create and grow artificial lifeforms capable of basic space flight. These can be used to replace our most simple ships in order to gain efficiency.
|
||||
72 en Mass Anti-matter Production Using newly acquired technologies our scientists have acheived mass production of anti-matter thus opening a brand new field of applications.
|
||||
73 en Singularity Housing Using the principles of Space-time folding, our engineers have improved our arcology design. Hyperspace and force-field generators must be integrated into our existing arcologies in order to allow our planets to house even more citizens.
|
||||
74 en Intelligent Materials Bringing sentience to the materials they use, our scientists provide us with wonderful new ways of building stuff.
|
||||
75 en Automated Factories Sir! Using sentient materials in our factories will allow us to gain production efficiency.
|
||||
76 en Wild Capitalism This law allows the industrial sector to use any means necessary to increase profit. As a consequence, base planetary income and industrial factory benefits are increased but military factories, research and happiness suffer from it.
|
||||
77 en Adaptive Plating Sir! Our scientists have come up with a new way to reduce battle damage. They have integrated intelligent materials in our ships' plating thus offering them better defensive abilities.
|
||||
78 en Anti-matter Generators Sir! Our scientists have designed a new way to produce energy. Equipping our factories with these anti-matter generators will improve our productivity.
|
||||
79 en Biological Subspace Control Sir! Our scientists have engineered some new astonishing lifeforms. These artificial creatures are capable of controlling subspace fields. This major discovery opens a new era for our future studies.
|
||||
80 en Wormhole Collapsing Sir, our scientists have devised a new defence. This technology allows our planets to build counter-measures that will allow them to prevent unwanted hyperspace windows from forming in orbit. This should prevent 10% of an enemy fleet from exiting hyperspace above the planet and delay them in hyperspace for 1 more hour.
|
||||
81 en Wormholes This technology applies space-time folding principles to spacebats, allowing your citizens to move freely between the planets in your empire. They will now be living in ecstacy as they will be able to visit their families, friends and dolphins.
|
||||
82 en Subspace Data conduit Applying wormhole theory to communications has allowed our scientists to create subspace conduits to transmit data, thus hiding it even better from enemy disruption techniques.
|
||||
83 en Self-sustained Arcologies Sir! By combining their expertise in hyperspace theory and biological engineering, our scientists have found a way to create "grown" housing that will provide room and nourishment for our citizens. This will allow us to sustain more people on our planets.
|
||||
84 en Matter Anti-matter Engines Sir! Our scientists have found a new application for matter anti-matter reactions: propulsion systems! This new line of engines should increase our ships efficiency greatly.
|
||||
85 en Biological Turrets Building our turrets with intelligent materials should allow us to take advantage of their sentience to gain in accuracy and fire power.
|
||||
86 en Localised Wormhole Destabilisation Applying wormhole collapsing technologies in a localised way allows us to disrupt subspace data conduits and other long range communication, rending them less efficient.
|
||||
87 en Wormhole Lockdown This law prevents your citizens from using the planetary gateways, cancelling the effects of the wormhole technology.
|
||||
88 en Wormhole Super Nova Sir! With this technology we can initiate a chain reaction on a planetary wormhole that will cause it to flare up and destroy anything in the vicinity, including the planet and scaring the living hell out of the planet's neighbours.
|
||||
89 en Biological Hyperspace Engines Sir! Our scientists have found a way to grow and nurture organic hyperspace engines. We will now be able to grow living capital ships, improving our fleets' efficiency.
|
||||
90 en Matter Anti-matter Missiles Using matter / anti-matter reactions in our warheads should greatly increase the damage caused by our ships.
|
||||
\.
|
||||
|
||||
|
||||
|
||||
-- Peacekeepers AI
|
||||
INSERT INTO player (userid, hidden) VALUES (
|
||||
(SELECT id FROM main.account WHERE name = 'AI>Peacekeepers'), 't'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'military_level', '0'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'pop_growth_factor', '1'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'if_productivity', '30'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'if_productivity_factor', '10'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'base_income', '2'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'factory_cost', '10'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'turret_cost', '20'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'mf_productivity', '10'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'mf_productivity_factor', '10'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'workunits_turret', '1500'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'workunits_gaship', '4500'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'workunits_fighter', '2000'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'workunits_cruiser', '20000'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'workunits_bcruiser', '22000'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'build_cost_turret', '400'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'build_cost_gaship', '750'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'build_cost_fighter', '500'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'build_cost_cruiser', '5000'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'build_cost_bcruiser', '15000'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'if_cost', '400'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'mf_cost', '400'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'battle_losses', '10'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'unhappiness_factor', '100'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'effective_fleet_power', '200'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'planet_max_pop', '10000'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'capital_ship_speed', '3'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'prevent_hs_exit', '0'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'planet_destruction', '0'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'turret_power', '10'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'gaship_power', '5'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'fighter_power', '30'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'cruiser_power', '120'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'bcruiser_power', '240'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'gaship_upkeep', '0'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'fighter_upkeep', '0'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'cruiser_upkeep', '0'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'bcruiser_upkeep', '0'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'research_percent', '200'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'gaship_space', '1'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'fighter_space', '1'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'cruiser_haul', '50'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'bcruiser_haul', '50'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'ecm_level', '4'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'eccm_level', '4'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'gaship_pop', '200'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'hs_beacon_level', '0'
|
||||
);
|
||||
INSERT INTO rule (player, name, value) VALUES (
|
||||
(SELECT id FROM player WHERE userid = (SELECT id FROM main.account WHERE name = 'AI>Peacekeepers')),
|
||||
'probe_tech', '0'
|
||||
);
|
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