Project: * Clean-up (Eclipse cruft, unused files, etc...) * Git-specific changes * Maven POMs clean-up and changes for the build system * Version set to 1.0.0-0 in the development branches * Maven plug-ins updated to latest versions * Very partial dev. documentation added
This commit is contained in:
parent
c74e30d5ba
commit
0665a760de
1439 changed files with 1020 additions and 1649 deletions
legacyworlds-server-data/db-structure
database.sqldb-config.txt
parts
000-schemas.sql010-data.sql020-functions.sql030-updates.sql
data
000-typedefs.sql010-i18n-data.sql020-prefs-data.sql030-users-data.sql035-session-data.sql040-admin-data.sql050-accounts-data.sql055-bugs-data.sql060-naming-data.sql070-constants-data.sql080-techs-data.sql090-buildables-data.sql100-universe-data.sql110-empires-data.sql120-construction-data.sql130-fleets-data.sql140-status-data.sql150-logs-data.sql160-battle-data.sql170-events-data.sql180-messages-data.sql
functions
000-defs-functions.sql002-sys-functions.sql005-logs-functions.sql010-constants-functions.sql020-naming-functions.sql030-tech-functions.sql035-users-view.sql040-empire-functions.sql050-computation-functions.sql060-universe-functions.sql070-users-functions.sql075-session-functions.sql080-buildings-functions.sql100-status-functions.sql110-prefs-functions.sql120-map-functions.sql140-planets-functions.sql150-battle-functions.sql160-battle-views.sql163-alliance-functions.sql165-fleets-functions.sql167-planet-list.sql170-event-functions.sql180-messages-functions.sql190-admin-functions.sql200-bugs-functions.sql210-admin-overview.sql
updates
54
legacyworlds-server-data/db-structure/database.sql
Normal file
54
legacyworlds-server-data/db-structure/database.sql
Normal file
|
@ -0,0 +1,54 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Main database script
|
||||
--
|
||||
-- Initialises the various roles and the database itself,
|
||||
-- then processes scripts from the "parts" directory.
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
-- Read configuration from file
|
||||
\set pgadmin `grep ^admin= db-config.txt | sed -e s/.*=//`
|
||||
\set dbname `grep ^db= db-config.txt | sed -e s/.*=//`
|
||||
\set dbuser `grep ^user= db-config.txt | sed -e s/.*=//`
|
||||
\set dbupass ''''`grep ^password= db-config.txt | sed -e s/.*=// -e "s/'/''/g"`''''
|
||||
|
||||
|
||||
-- Connect to the main system database
|
||||
\c postgres :pgadmin
|
||||
|
||||
-- Drop the database and users if they exist
|
||||
DROP DATABASE IF EXISTS :dbname;
|
||||
DROP ROLE IF EXISTS :dbuser;
|
||||
|
||||
-- Create the LW users
|
||||
CREATE ROLE :dbuser WITH LOGIN ENCRYPTED PASSWORD :dbupass;
|
||||
|
||||
-- Create the database
|
||||
CREATE DATABASE :dbname ENCODING='UTF8' TEMPLATE=template0;
|
||||
GRANT CONNECT ON DATABASE :dbname TO :dbuser;
|
||||
|
||||
|
||||
-- Connect to the LW database with the PostgreSQL admin user
|
||||
\c :dbname :pgadmin
|
||||
|
||||
-- Register PL/PgSQL
|
||||
CREATE TRUSTED PROCEDURAL LANGUAGE plpgsql;
|
||||
|
||||
BEGIN;
|
||||
|
||||
-- Create database schemas
|
||||
\i parts/000-schemas.sql
|
||||
|
||||
-- Process structure definition scripts
|
||||
\i parts/010-data.sql
|
||||
|
||||
-- Process functions and views definition scripts
|
||||
\i parts/020-functions.sql
|
||||
|
||||
-- Process game update functions
|
||||
\i parts/030-updates.sql
|
||||
|
||||
COMMIT;
|
4
legacyworlds-server-data/db-structure/db-config.txt
Normal file
4
legacyworlds-server-data/db-structure/db-config.txt
Normal file
|
@ -0,0 +1,4 @@
|
|||
admin=tseeker
|
||||
db=lwb6
|
||||
user=lwb6
|
||||
password=test
|
46
legacyworlds-server-data/db-structure/parts/000-schemas.sql
Normal file
46
legacyworlds-server-data/db-structure/parts/000-schemas.sql
Normal file
|
@ -0,0 +1,46 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Creates schemas
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
CREATE SCHEMA admin;
|
||||
GRANT USAGE ON SCHEMA admin TO :dbuser;
|
||||
|
||||
CREATE SCHEMA battles;
|
||||
GRANT USAGE ON SCHEMA battles TO :dbuser;
|
||||
|
||||
CREATE SCHEMA bugs;
|
||||
GRANT USAGE ON SCHEMA bugs TO :dbuser;
|
||||
|
||||
CREATE SCHEMA defs;
|
||||
GRANT USAGE ON SCHEMA defs TO :dbuser;
|
||||
|
||||
CREATE SCHEMA events;
|
||||
GRANT USAGE ON SCHEMA events TO :dbuser;
|
||||
|
||||
CREATE SCHEMA emp;
|
||||
GRANT USAGE ON SCHEMA emp TO :dbuser;
|
||||
|
||||
CREATE SCHEMA fleets;
|
||||
GRANT USAGE ON SCHEMA fleets TO :dbuser;
|
||||
|
||||
CREATE SCHEMA msgs;
|
||||
GRANT USAGE ON SCHEMA msgs TO :dbuser;
|
||||
|
||||
CREATE SCHEMA naming;
|
||||
GRANT USAGE ON SCHEMA naming TO :dbuser;
|
||||
|
||||
CREATE SCHEMA sys;
|
||||
GRANT USAGE ON SCHEMA sys TO :dbuser;
|
||||
|
||||
CREATE SCHEMA tech;
|
||||
GRANT USAGE ON SCHEMA tech TO :dbuser;
|
||||
|
||||
CREATE SCHEMA users;
|
||||
GRANT USAGE ON SCHEMA users TO :dbuser;
|
||||
|
||||
CREATE SCHEMA verse;
|
||||
GRANT USAGE ON SCHEMA verse TO :dbuser;
|
29
legacyworlds-server-data/db-structure/parts/010-data.sql
Normal file
29
legacyworlds-server-data/db-structure/parts/010-data.sql
Normal file
|
@ -0,0 +1,29 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Structures creation
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
\i parts/data/000-typedefs.sql
|
||||
\i parts/data/010-i18n-data.sql
|
||||
\i parts/data/020-prefs-data.sql
|
||||
\i parts/data/030-users-data.sql
|
||||
\i parts/data/035-session-data.sql
|
||||
\i parts/data/040-admin-data.sql
|
||||
\i parts/data/050-accounts-data.sql
|
||||
\i parts/data/055-bugs-data.sql
|
||||
\i parts/data/060-naming-data.sql
|
||||
\i parts/data/070-constants-data.sql
|
||||
\i parts/data/080-techs-data.sql
|
||||
\i parts/data/090-buildables-data.sql
|
||||
\i parts/data/100-universe-data.sql
|
||||
\i parts/data/110-empires-data.sql
|
||||
\i parts/data/120-construction-data.sql
|
||||
\i parts/data/130-fleets-data.sql
|
||||
\i parts/data/140-status-data.sql
|
||||
\i parts/data/150-logs-data.sql
|
||||
\i parts/data/160-battle-data.sql
|
||||
\i parts/data/170-events-data.sql
|
||||
\i parts/data/180-messages-data.sql
|
|
@ -0,0 +1,36 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Functions and views
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
\i parts/functions/000-defs-functions.sql
|
||||
\i parts/functions/002-sys-functions.sql
|
||||
\i parts/functions/005-logs-functions.sql
|
||||
\i parts/functions/010-constants-functions.sql
|
||||
\i parts/functions/020-naming-functions.sql
|
||||
\i parts/functions/030-tech-functions.sql
|
||||
\i parts/functions/035-users-view.sql
|
||||
\i parts/functions/040-empire-functions.sql
|
||||
\i parts/functions/050-computation-functions.sql
|
||||
\i parts/functions/060-universe-functions.sql
|
||||
\i parts/functions/070-users-functions.sql
|
||||
\i parts/functions/075-session-functions.sql
|
||||
\i parts/functions/080-buildings-functions.sql
|
||||
\i parts/functions/100-status-functions.sql
|
||||
\i parts/functions/110-prefs-functions.sql
|
||||
\i parts/functions/120-map-functions.sql
|
||||
\i parts/functions/140-planets-functions.sql
|
||||
\i parts/functions/150-battle-functions.sql
|
||||
\i parts/functions/160-battle-views.sql
|
||||
\i parts/functions/163-alliance-functions.sql
|
||||
\i parts/functions/165-fleets-functions.sql
|
||||
\i parts/functions/167-planet-list.sql
|
||||
\i parts/functions/170-event-functions.sql
|
||||
\i parts/functions/180-messages-functions.sql
|
||||
\i parts/functions/190-admin-functions.sql
|
||||
\i parts/functions/200-bugs-functions.sql
|
||||
\i parts/functions/210-admin-overview.sql
|
||||
|
22
legacyworlds-server-data/db-structure/parts/030-updates.sql
Normal file
22
legacyworlds-server-data/db-structure/parts/030-updates.sql
Normal file
|
@ -0,0 +1,22 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Game updates
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
\i parts/updates/000-updates-ctrl.sql
|
||||
\i parts/updates/010-empire-money.sql
|
||||
\i parts/updates/020-empire-research.sql
|
||||
\i parts/updates/025-empire-debt.sql
|
||||
\i parts/updates/030-fleet-arrivals.sql
|
||||
\i parts/updates/040-fleet-movements.sql
|
||||
\i parts/updates/050-fleet-status.sql
|
||||
\i parts/updates/060-planet-battle.sql
|
||||
\i parts/updates/070-planet-abandon.sql
|
||||
\i parts/updates/080-planet-construction.sql
|
||||
\i parts/updates/090-planet-military.sql
|
||||
\i parts/updates/100-planet-population.sql
|
||||
\i parts/updates/110-planet-money.sql
|
|
@ -0,0 +1,53 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Type definitions
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
-- Processing status
|
||||
CREATE TYPE processing_status
|
||||
AS ENUM ( 'FUTURE', 'PROCESSING', 'PROCESSED' );
|
||||
|
||||
-- Building output types
|
||||
CREATE TYPE building_output_type
|
||||
AS ENUM ( 'CASH', 'POP', 'DEF', 'WORK' );
|
||||
|
||||
-- Fleet status
|
||||
CREATE TYPE fleet_status
|
||||
AS ENUM ( 'AVAILABLE', 'DEPLOYING' , 'REDEPLOYING' , 'REDIRECTING' );
|
||||
|
||||
-- Log levels
|
||||
CREATE TYPE log_level
|
||||
AS ENUM ( 'TRACE' , 'DEBUG' , 'INFO' , 'WARNING' , 'ERROR' );
|
||||
|
||||
-- Log types
|
||||
CREATE TYPE log_type
|
||||
AS ENUM ( 'SYS' , 'USERS' , 'ADMIN' );
|
||||
|
||||
-- Update types
|
||||
CREATE TYPE update_type AS ENUM (
|
||||
'EMPIRE_MONEY' ,
|
||||
'EMPIRE_RESEARCH' ,
|
||||
'EMPIRE_DEBT' ,
|
||||
'PLANET_FLEET_ARRIVALS' ,
|
||||
'PLANET_FLEET_MOVEMENTS' ,
|
||||
'PLANET_FLEET_STATUS' ,
|
||||
'PLANET_BATTLE_START' ,
|
||||
'PLANET_BATTLE_MAIN' ,
|
||||
'PLANET_BATTLE_END' ,
|
||||
'PLANET_ABANDON' ,
|
||||
'PLANET_CONSTRUCTION' ,
|
||||
'PLANET_MILITARY' ,
|
||||
'PLANET_POPULATION' ,
|
||||
'PLANET_MONEY'
|
||||
);
|
||||
|
||||
-- Types of recapitulative e-mail messages
|
||||
CREATE TYPE recap_type
|
||||
AS ENUM ( 'ADMIN' , 'MSG', 'ERROR' );
|
||||
|
||||
-- Empire relations
|
||||
CREATE TYPE empire_relation_type
|
||||
AS ENUM ('OWN' , 'ALLIED' , 'ENEMY');
|
|
@ -0,0 +1,53 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Translations
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
--
|
||||
-- Languages
|
||||
--
|
||||
CREATE TABLE defs.languages(
|
||||
id SERIAL PRIMARY KEY ,
|
||||
language VARCHAR(5) NOT NULL ,
|
||||
name VARCHAR(48) NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_languages_lid
|
||||
ON defs.languages (language);
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Internationalised strings
|
||||
--
|
||||
CREATE TABLE defs.strings(
|
||||
id SERIAL PRIMARY KEY ,
|
||||
name VARCHAR(64) NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_strings_id
|
||||
ON defs.strings (name);
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Translations
|
||||
--
|
||||
CREATE TABLE defs.translations(
|
||||
lang_id INT NOT NULL ,
|
||||
string_id INT NOT NULL ,
|
||||
translated_string TEXT NOT NULL ,
|
||||
PRIMARY KEY (lang_id, string_id)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_translations_string
|
||||
ON defs.translations (string_id);
|
||||
|
||||
ALTER TABLE defs.translations
|
||||
ADD CONSTRAINT fk_translation_language
|
||||
FOREIGN KEY (lang_id) REFERENCES defs.languages ,
|
||||
ADD CONSTRAINT fk_translation_string
|
||||
FOREIGN KEY (string_id) REFERENCES defs.strings;
|
|
@ -0,0 +1,57 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Preference definitions
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Preference groups
|
||||
--
|
||||
CREATE TABLE defs.preference_groups(
|
||||
id SERIAL PRIMARY KEY ,
|
||||
name VARCHAR(32) NOT NULL ,
|
||||
display_id INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_prefgroups_name
|
||||
ON defs.preference_groups (name);
|
||||
CREATE INDEX idx_prefgroups_dispname
|
||||
ON defs.preference_groups (display_id);
|
||||
|
||||
ALTER TABLE defs.preference_groups
|
||||
ADD CONSTRAINT fk_prefgroups_display
|
||||
FOREIGN KEY (display_id) REFERENCES defs.strings;
|
||||
|
||||
|
||||
--
|
||||
-- Preference definitions
|
||||
--
|
||||
CREATE TABLE defs.preference_definitions(
|
||||
id SERIAL PRIMARY KEY ,
|
||||
group_id INT NOT NULL ,
|
||||
name VARCHAR(32) NOT NULL ,
|
||||
disp_name_id INT NOT NULL ,
|
||||
disp_desc_id INT NOT NULL ,
|
||||
java_type VARCHAR( 255 ) NOT NULL ,
|
||||
default_value TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_prefdefs_group
|
||||
ON defs.preference_definitions (group_id);
|
||||
CREATE UNIQUE INDEX idx_prefdefs_name
|
||||
ON defs.preference_definitions (name);
|
||||
CREATE INDEX idx_prefdefs_dispname
|
||||
ON defs.preference_definitions (disp_name_id);
|
||||
CREATE INDEX idx_prefdefs_dispdesc
|
||||
ON defs.preference_definitions (disp_desc_id);
|
||||
|
||||
ALTER TABLE defs.preference_definitions
|
||||
ADD CONSTRAINT fk_prefdefs_group
|
||||
FOREIGN KEY (group_id) REFERENCES defs.preference_groups ,
|
||||
ADD CONSTRAINT fk_prefdefs_dispname
|
||||
FOREIGN KEY (disp_name_id) REFERENCES defs.strings ,
|
||||
ADD CONSTRAINT fk_prefdefs_dispdesc
|
||||
FOREIGN KEY (disp_desc_id) REFERENCES defs.strings;
|
|
@ -0,0 +1,111 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- User management tables
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
--
|
||||
-- Identifiers sequence for users
|
||||
--
|
||||
CREATE SEQUENCE users.identifiers_seq;
|
||||
|
||||
|
||||
--
|
||||
-- E-mail addresses
|
||||
--
|
||||
CREATE TABLE users.addresses(
|
||||
id INT DEFAULT nextval('users.identifiers_seq') NOT NULL PRIMARY KEY ,
|
||||
address VARCHAR(255) NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_addresses_address
|
||||
ON users.addresses (lower(address));
|
||||
|
||||
|
||||
--
|
||||
-- User credentials
|
||||
--
|
||||
CREATE TABLE users.credentials(
|
||||
address_id INT NOT NULL PRIMARY KEY,
|
||||
pass_md5 CHAR(32) NOT NULL ,
|
||||
pass_sha1 CHAR(40) NOT NULL ,
|
||||
credits INT NOT NULL CHECK (credits >= 0) ,
|
||||
language_id INT NOT NULL
|
||||
);
|
||||
|
||||
ALTER TABLE users.credentials
|
||||
ADD CONSTRAINT fk_credentials_id
|
||||
FOREIGN KEY (address_id) REFERENCES users.addresses
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_credentials_language
|
||||
FOREIGN KEY (language_id) REFERENCES defs.languages;
|
||||
|
||||
|
||||
--
|
||||
-- Validation keys
|
||||
--
|
||||
CREATE TABLE users.validation_keys(
|
||||
credentials_id INT NOT NULL PRIMARY KEY ,
|
||||
token CHAR( 64 ) NOT NULL ,
|
||||
created TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_validationkeys_created
|
||||
ON users.validation_keys (created);
|
||||
|
||||
ALTER TABLE users.validation_keys
|
||||
ADD CONSTRAINT fk_validationkeys_id
|
||||
FOREIGN KEY (credentials_id) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Password recovery
|
||||
--
|
||||
CREATE TABLE users.pwd_recovery_requests(
|
||||
credentials_id INT NOT NULL PRIMARY KEY ,
|
||||
token CHAR( 64 ) NOT NULL ,
|
||||
used BOOLEAN NOT NULL
|
||||
DEFAULT FALSE ,
|
||||
created TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_pwdrecovery_created
|
||||
ON users.pwd_recovery_requests (created);
|
||||
|
||||
ALTER TABLE users.pwd_recovery_requests
|
||||
ADD CONSTRAINT fk_pwdrecovery_id
|
||||
FOREIGN KEY (credentials_id) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Mail address change requests
|
||||
--
|
||||
CREATE TABLE users.address_change_requests(
|
||||
credentials_id INT NOT NULL PRIMARY KEY ,
|
||||
address_id INT NOT NULL ,
|
||||
token CHAR( 64 ) NOT NULL ,
|
||||
used BOOLEAN NOT NULL
|
||||
DEFAULT FALSE ,
|
||||
created TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT NOW()
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_addrchangereq_address
|
||||
ON users.address_change_requests (address_id);
|
||||
CREATE INDEX idx_addrchangereq_created
|
||||
ON users.address_change_requests (created);
|
||||
|
||||
ALTER TABLE users.address_change_requests
|
||||
ADD CONSTRAINT fk_addrchangereq_id
|
||||
FOREIGN KEY (credentials_id) REFERENCES users.credentials ON DELETE CASCADE ON UPDATE CASCADE,
|
||||
ADD CONSTRAINT fk_addrchangereq_address
|
||||
FOREIGN KEY (address_id) REFERENCES users.addresses ON DELETE CASCADE;
|
|
@ -0,0 +1,92 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- User sessions tables
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Session client type definitions
|
||||
--
|
||||
|
||||
CREATE TABLE defs.session_clients(
|
||||
id SERIAL PRIMARY KEY ,
|
||||
name VARCHAR( 16 ) NOT NULL UNIQUE ,
|
||||
exclusive BOOLEAN NOT NULL
|
||||
);
|
||||
|
||||
--
|
||||
-- Default session client types
|
||||
--
|
||||
|
||||
INSERT INTO defs.session_clients ( name , exclusive )
|
||||
VALUES( 'web' , TRUE );
|
||||
INSERT INTO defs.session_clients ( name , exclusive )
|
||||
VALUES( 'vac_end' , FALSE );
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Types of session termination
|
||||
--
|
||||
|
||||
CREATE TYPE session_termination_type
|
||||
AS ENUM( 'MANUAL' , 'GONE' , 'EXPIRED' , 'EXCLUSIVE' , 'SERVER' );
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- User sessions start
|
||||
--
|
||||
|
||||
CREATE TABLE users.session_starts(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
credentials_id INT NOT NULL ,
|
||||
client_id INT NOT NULL ,
|
||||
session VARCHAR( 64 ) NOT NULL ,
|
||||
started TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( ) ,
|
||||
from_address VARCHAR( 64 ) NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_sessstart_credentials
|
||||
ON users.session_starts ( credentials_id );
|
||||
|
||||
CREATE INDEX idx_sessstart_client
|
||||
ON users.session_starts ( client_id );
|
||||
|
||||
CREATE INDEX idx_sessstart_started
|
||||
ON users.session_starts ( started );
|
||||
|
||||
ALTER TABLE users.session_starts
|
||||
ADD CONSTRAINT fk_sessstart_credentials
|
||||
FOREIGN KEY ( credentials_id ) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE ,
|
||||
ADD CONSTRAINT fk_sessstart_client
|
||||
FOREIGN KEY ( client_id ) REFERENCES defs.session_clients;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- User sessions end
|
||||
--
|
||||
|
||||
CREATE TABLE users.session_ends(
|
||||
id BIGINT NOT NULL PRIMARY KEY ,
|
||||
ended TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( ) ,
|
||||
end_type session_termination_type NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_sessend_ended
|
||||
ON users.session_ends ( ended );
|
||||
|
||||
ALTER TABLE users.session_ends
|
||||
ADD CONSTRAINT fk_sessend_id
|
||||
FOREIGN KEY ( id ) REFERENCES users.session_starts
|
||||
ON DELETE CASCADE;
|
||||
|
|
@ -0,0 +1,169 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Administrative tables
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
--
|
||||
-- Administrators
|
||||
--
|
||||
CREATE TABLE admin.administrators(
|
||||
id SERIAL NOT NULL PRIMARY KEY ,
|
||||
appear_as VARCHAR( 48 ) NOT NULL ,
|
||||
pass_md5 CHAR(32) NOT NULL ,
|
||||
pass_sha1 CHAR(40) NOT NULL ,
|
||||
privileges INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_administrators_appearas
|
||||
ON admin.administrators( lower(appear_as) );
|
||||
|
||||
|
||||
--
|
||||
-- Administrators <-> credentials
|
||||
--
|
||||
CREATE TABLE admin.admin_credentials(
|
||||
administrator_id INT NOT NULL ,
|
||||
credentials_id INT NOT NULL ,
|
||||
PRIMARY KEY(administrator_id)
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_admincreds_creds
|
||||
ON admin.admin_credentials( credentials_id );
|
||||
|
||||
ALTER TABLE admin.admin_credentials
|
||||
ADD CONSTRAINT fk_admincreds_admin
|
||||
FOREIGN KEY (administrator_id) REFERENCES admin.administrators ,
|
||||
ADD CONSTRAINT fk_admincreds_creds
|
||||
FOREIGN KEY (credentials_id) REFERENCES users.credentials
|
||||
ON UPDATE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Ban requests
|
||||
--
|
||||
CREATE TABLE admin.ban_requests(
|
||||
id SERIAL NOT NULL PRIMARY KEY ,
|
||||
requested_by INT NOT NULL ,
|
||||
reason TEXT NOT NULL ,
|
||||
requested TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_banrequests_requestedby
|
||||
ON admin.ban_requests( requested_by );
|
||||
|
||||
ALTER TABLE admin.ban_requests
|
||||
ADD CONSTRAINT fk_banrequests_requestedby
|
||||
FOREIGN KEY (requested_by) REFERENCES admin.administrators;
|
||||
|
||||
|
||||
--
|
||||
-- Active ban requests
|
||||
--
|
||||
CREATE TABLE admin.active_ban_requests(
|
||||
request_id INT NOT NULL PRIMARY KEY ,
|
||||
credentials_id INT NOT NULL ,
|
||||
validated BOOLEAN NOT NULL
|
||||
DEFAULT FALSE
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_activebanrequests_creds
|
||||
ON admin.active_ban_requests (credentials_id);
|
||||
|
||||
ALTER TABLE admin.active_ban_requests
|
||||
ADD CONSTRAINT fk_activebanrequests_request
|
||||
FOREIGN KEY (request_id) REFERENCES admin.ban_requests ,
|
||||
ADD CONSTRAINT fk_activebanrequests_creds
|
||||
FOREIGN KEY (credentials_id) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Archived ban requests
|
||||
--
|
||||
CREATE TABLE admin.archived_ban_requests(
|
||||
request_id INT NOT NULL PRIMARY KEY ,
|
||||
credentials_id INT NOT NULL ,
|
||||
updated TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_archivedbanrequests_creds
|
||||
ON admin.archived_ban_requests (credentials_id);
|
||||
|
||||
ALTER TABLE admin.archived_ban_requests
|
||||
ADD CONSTRAINT fk_archivedbanrequests_request
|
||||
FOREIGN KEY (request_id) REFERENCES admin.ban_requests ,
|
||||
ADD CONSTRAINT fk_archivedbanrequests_creds
|
||||
FOREIGN KEY (credentials_id) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Rejected ban requests
|
||||
--
|
||||
CREATE TABLE admin.rejected_ban_requests(
|
||||
request_id INT NOT NULL PRIMARY KEY ,
|
||||
rejected_by INT NOT NULL ,
|
||||
reason TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_rejectedbanrequests_rejected
|
||||
ON admin.rejected_ban_requests (rejected_by);
|
||||
|
||||
ALTER TABLE admin.rejected_ban_requests
|
||||
ADD CONSTRAINT fk_rejectedbanrequests_request
|
||||
FOREIGN KEY (request_id) REFERENCES admin.ban_requests ,
|
||||
ADD CONSTRAINT fk_rejectedbanrequests_rejected
|
||||
FOREIGN KEY (rejected_by) REFERENCES admin.administrators;
|
||||
|
||||
|
||||
--
|
||||
-- Validated ban requests
|
||||
--
|
||||
CREATE TABLE admin.validated_ban_requests(
|
||||
request_id INT NOT NULL PRIMARY KEY ,
|
||||
validated_by INT NOT NULL ,
|
||||
validated TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_validatedbanrequests_validated
|
||||
ON admin.validated_ban_requests (validated_by);
|
||||
|
||||
ALTER TABLE admin.validated_ban_requests
|
||||
ADD CONSTRAINT fk_validatedbanrequests_request
|
||||
FOREIGN KEY (request_id) REFERENCES admin.ban_requests ,
|
||||
ADD CONSTRAINT fk_validatedbanrequests_rejected
|
||||
FOREIGN KEY (validated_by) REFERENCES admin.administrators;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Warnings to users
|
||||
--
|
||||
|
||||
CREATE TABLE admin.warnings (
|
||||
credentials_id INT NOT NULL PRIMARY KEY ,
|
||||
warnings INT NOT NULL
|
||||
DEFAULT 1
|
||||
CHECK( warnings >= 0 ) ,
|
||||
last_received TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_warnings_received
|
||||
ON admin.warnings( last_received )
|
||||
WHERE warnings > 0;
|
||||
|
||||
ALTER TABLE admin.warnings
|
||||
ADD CONSTRAINT fk_warnings_credentials
|
||||
FOREIGN KEY ( credentials_id ) REFERENCES users.credentials
|
||||
ON UPDATE CASCADE ON DELETE CASCADE;
|
|
@ -0,0 +1,137 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Account tables
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
--
|
||||
-- Active account
|
||||
--
|
||||
CREATE TABLE users.active_accounts(
|
||||
credentials_id INT NOT NULL PRIMARY KEY ,
|
||||
vacation_credits INT NOT NULL CHECK( vacation_credits >= 0 )
|
||||
);
|
||||
|
||||
ALTER TABLE users.active_accounts
|
||||
ADD CONSTRAINT fk_activeaccounts_creds
|
||||
FOREIGN KEY (credentials_id) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Vacation credits
|
||||
--
|
||||
CREATE TABLE users.vacations(
|
||||
account_id INT NOT NULL PRIMARY KEY ,
|
||||
since TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL ,
|
||||
status processing_status NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_vacations_status
|
||||
ON users.vacations (since, status);
|
||||
|
||||
ALTER TABLE users.vacations
|
||||
ADD CONSTRAINT fk_vacations_accounts
|
||||
FOREIGN KEY (account_id) REFERENCES users.active_accounts
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Preferences
|
||||
--
|
||||
|
||||
CREATE TABLE users.preferences(
|
||||
account_id INT NOT NULL ,
|
||||
definition_id INT NOT NULL ,
|
||||
pref_value TEXT NOT NULL ,
|
||||
PRIMARY KEY (account_id,definition_id)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_preferences_definition
|
||||
ON users.preferences( definition_id );
|
||||
|
||||
ALTER TABLE users.preferences
|
||||
ADD CONSTRAINT fk_preferences_accounts
|
||||
FOREIGN KEY (account_id) REFERENCES users.active_accounts
|
||||
ON DELETE CASCADE ON UPDATE CASCADE ,
|
||||
ADD CONSTRAINT fk_preferences_definition
|
||||
FOREIGN KEY (definition_id) REFERENCES defs.preference_definitions
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Inactive accounts
|
||||
--
|
||||
|
||||
CREATE TABLE users.inactive_accounts(
|
||||
credentials_id INT NOT NULL PRIMARY KEY ,
|
||||
since TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL ,
|
||||
status processing_status NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_inactiveaccounts_status
|
||||
ON users.vacations (since, status);
|
||||
|
||||
ALTER TABLE users.inactive_accounts
|
||||
ADD CONSTRAINT fk_inactiveaccounts_creds
|
||||
FOREIGN KEY (credentials_id) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Account de-activation reasons
|
||||
--
|
||||
CREATE TABLE users.reasons(
|
||||
account_id INT NOT NULL PRIMARY KEY ,
|
||||
reason TEXT NOT NULL
|
||||
);
|
||||
|
||||
ALTER TABLE users.reasons
|
||||
ADD CONSTRAINT fk_reasons_account
|
||||
FOREIGN KEY (account_id) REFERENCES users.inactive_accounts
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Bans
|
||||
--
|
||||
CREATE TABLE users.bans(
|
||||
account_id INT NOT NULL PRIMARY KEY ,
|
||||
ban_id INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_bans_banrequest
|
||||
ON users.bans (ban_id);
|
||||
|
||||
ALTER TABLE users.bans
|
||||
ADD CONSTRAINT fk_bans_account
|
||||
FOREIGN KEY (account_id) REFERENCES users.inactive_accounts
|
||||
ON DELETE CASCADE ON UPDATE CASCADE,
|
||||
ADD CONSTRAINT fk_bans_ban
|
||||
FOREIGN KEY (ban_id) REFERENCES admin.validated_ban_requests;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Table that stores inactivity warning e-mail status
|
||||
--
|
||||
|
||||
CREATE TABLE users.inactivity_emails(
|
||||
account_id INT NOT NULL PRIMARY KEY ,
|
||||
mail_sent TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_inactivitymails_sent
|
||||
ON users.inactivity_emails ( mail_sent );
|
||||
|
||||
ALTER TABLE users.inactivity_emails
|
||||
ADD CONSTRAINT fk_inactivitymails_account
|
||||
FOREIGN KEY ( account_id ) REFERENCES users.active_accounts
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
|
@ -0,0 +1,273 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Tables that support the bug tracking system
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Bug event types
|
||||
--
|
||||
|
||||
CREATE TYPE bug_event_type
|
||||
AS ENUM( 'INIT' , 'MERGE' , 'STATUS' , 'COMMENT' , 'VISIBILITY' );
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Bug statuses
|
||||
--
|
||||
|
||||
CREATE TYPE bug_status_type
|
||||
AS ENUM( 'OPEN' , 'NOT_A_BUG' , 'WONT_FIX' , 'RESOLVED' );
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Bug submitters
|
||||
--
|
||||
|
||||
CREATE TABLE bugs.submitters (
|
||||
submitter_id BIGSERIAL PRIMARY KEY ,
|
||||
is_admin BOOLEAN NOT NULL ,
|
||||
name VARCHAR( 64 ) NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_submitters_isadmin
|
||||
ON bugs.submitters ( is_admin );
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Bug submitters - administrators
|
||||
--
|
||||
|
||||
CREATE TABLE bugs.admin_submitters(
|
||||
submitter_id BIGINT PRIMARY KEY ,
|
||||
admin_id INT NOT NULL UNIQUE
|
||||
);
|
||||
|
||||
ALTER TABLE bugs.admin_submitters
|
||||
ADD CONSTRAINT fk_adminsubs_submitter
|
||||
FOREIGN KEY ( submitter_id ) REFERENCES bugs.submitters ,
|
||||
ADD CONSTRAINT fk_adminsubs_admin
|
||||
FOREIGN KEY ( admin_id ) REFERENCES admin.administrators
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Bug submitters - users
|
||||
--
|
||||
|
||||
CREATE TABLE bugs.user_submitters(
|
||||
submitter_id BIGINT PRIMARY KEY ,
|
||||
account_id INT NOT NULL UNIQUE
|
||||
);
|
||||
|
||||
ALTER TABLE bugs.user_submitters
|
||||
ADD CONSTRAINT fk_usersubs_submitter
|
||||
FOREIGN KEY ( submitter_id ) REFERENCES bugs.submitters ,
|
||||
ADD CONSTRAINT fk_usersubs_account
|
||||
FOREIGN KEY ( account_id ) REFERENCES users.active_accounts
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Report groups
|
||||
--
|
||||
|
||||
CREATE TABLE bugs.groups(
|
||||
group_id BIGSERIAL PRIMARY KEY
|
||||
);
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Report events - main table
|
||||
--
|
||||
|
||||
CREATE TABLE bugs.events(
|
||||
event_id BIGSERIAL PRIMARY KEY ,
|
||||
group_id BIGINT NOT NULL ,
|
||||
submitter_id BIGINT NOT NULL ,
|
||||
e_type bug_event_type NOT NULL ,
|
||||
t TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_events_group
|
||||
ON bugs.events( group_id );
|
||||
|
||||
CREATE INDEX idx_events_submitter
|
||||
ON bugs.events( submitter_id );
|
||||
|
||||
CREATE INDEX idx_events_time
|
||||
ON bugs.events( t );
|
||||
|
||||
ALTER TABLE bugs.events
|
||||
ADD CONSTRAINT fk_events_group
|
||||
FOREIGN KEY ( group_id ) REFERENCES bugs.groups ,
|
||||
ADD CONSTRAINT fk_events_submitter
|
||||
FOREIGN KEY ( submitter_id ) REFERENCES bugs.submitters;
|
||||
|
||||
GRANT SELECT ON bugs.events TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Report events - initial reports
|
||||
--
|
||||
|
||||
CREATE TABLE bugs.initial_report_events(
|
||||
event_id BIGINT PRIMARY KEY ,
|
||||
title VARCHAR( 128 ) NOT NULL ,
|
||||
description TEXT NOT NULL
|
||||
);
|
||||
|
||||
ALTER TABLE bugs.initial_report_events
|
||||
ADD CONSTRAINT fk_initialreports_event
|
||||
FOREIGN KEY ( event_id ) REFERENCES bugs.events;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Report events - mergers
|
||||
--
|
||||
|
||||
CREATE TABLE bugs.merge_events(
|
||||
event_id BIGINT PRIMARY KEY ,
|
||||
initial_post_id BIGINT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_mergers_initialpost
|
||||
ON bugs.merge_events( initial_post_id );
|
||||
|
||||
ALTER TABLE bugs.merge_events
|
||||
ADD CONSTRAINT fk_mergers_event
|
||||
FOREIGN KEY ( event_id ) REFERENCES bugs.events ,
|
||||
ADD CONSTRAINT fk_mergers_initial
|
||||
FOREIGN KEY ( initial_post_id ) REFERENCES bugs.initial_report_events;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Report events - status change
|
||||
--
|
||||
|
||||
CREATE TABLE bugs.status_change_events(
|
||||
event_id BIGINT PRIMARY KEY ,
|
||||
status bug_status_type NOT NULL
|
||||
);
|
||||
|
||||
ALTER TABLE bugs.status_change_events
|
||||
ADD CONSTRAINT fk_statuschanges_event
|
||||
FOREIGN KEY ( event_id ) REFERENCES bugs.events;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Report events - comments
|
||||
--
|
||||
|
||||
CREATE TABLE bugs.comment_events(
|
||||
event_id BIGINT PRIMARY KEY ,
|
||||
comment TEXT NOT NULL ,
|
||||
visible BOOLEAN NOT NULL
|
||||
);
|
||||
|
||||
ALTER TABLE bugs.comment_events
|
||||
ADD CONSTRAINT fk_comments_event
|
||||
FOREIGN KEY ( event_id ) REFERENCES bugs.events;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Report events - visibility changes
|
||||
--
|
||||
|
||||
CREATE TABLE bugs.visibility_events(
|
||||
event_id BIGINT PRIMARY KEY ,
|
||||
visible BOOLEAN NOT NULL
|
||||
);
|
||||
|
||||
|
||||
ALTER TABLE bugs.visibility_events
|
||||
ADD CONSTRAINT fk_visibility_event
|
||||
FOREIGN KEY ( event_id ) REFERENCES bugs.events;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Account status information submitted along with bug reports by players
|
||||
--
|
||||
|
||||
CREATE TABLE bugs.account_status_data(
|
||||
event_id BIGINT PRIMARY KEY ,
|
||||
account_status TEXT
|
||||
);
|
||||
|
||||
ALTER TABLE bugs.account_status_data
|
||||
ADD CONSTRAINT fk_accountstatus_event
|
||||
FOREIGN KEY ( event_id ) REFERENCES bugs.initial_report_events;
|
||||
|
||||
GRANT SELECT ON bugs.account_status_data TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- View status - administrators
|
||||
--
|
||||
|
||||
CREATE TABLE bugs.admin_view_status(
|
||||
group_id BIGINT NOT NULL ,
|
||||
admin_id INT NOT NULL ,
|
||||
last_view TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL DEFAULT now( ) ,
|
||||
PRIMARY KEY( group_id , admin_id )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_adminview_admin
|
||||
ON bugs.admin_view_status ( admin_id );
|
||||
|
||||
CREATE INDEX idx_adminview_lastview
|
||||
ON bugs.admin_view_status ( last_view );
|
||||
|
||||
ALTER TABLE bugs.admin_view_status
|
||||
ADD CONSTRAINT fk_adminview_group
|
||||
FOREIGN KEY ( group_id ) REFERENCES bugs.groups
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_adminview_admin
|
||||
FOREIGN KEY ( admin_id ) REFERENCES admin.administrators;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- View status - players
|
||||
--
|
||||
|
||||
CREATE TABLE bugs.user_view_status(
|
||||
group_id BIGINT NOT NULL ,
|
||||
user_id INT NOT NULL ,
|
||||
last_view TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL DEFAULT now( ) ,
|
||||
PRIMARY KEY( group_id , user_id )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_userview_user
|
||||
ON bugs.user_view_status ( user_id );
|
||||
|
||||
CREATE INDEX idx_userview_lastview
|
||||
ON bugs.user_view_status ( last_view );
|
||||
|
||||
ALTER TABLE bugs.user_view_status
|
||||
ADD CONSTRAINT fk_userview_group
|
||||
FOREIGN KEY ( group_id ) REFERENCES bugs.groups
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_userview_user
|
||||
FOREIGN KEY ( user_id ) REFERENCES users.active_accounts
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
|
@ -0,0 +1,109 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Empire/map object names
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Banned names
|
||||
--
|
||||
|
||||
CREATE TABLE naming.banned_names(
|
||||
name VARCHAR(20) NOT NULL ,
|
||||
added_by INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_bannednames_name
|
||||
ON naming.banned_names( lower(name) );
|
||||
CREATE INDEX idx_bannednames_addedby
|
||||
ON naming.banned_names (added_by);
|
||||
|
||||
ALTER TABLE naming.banned_names
|
||||
ADD CONSTRAINT fk_bannednames_addedby
|
||||
FOREIGN KEY (added_by) REFERENCES admin.administrators;
|
||||
|
||||
|
||||
--
|
||||
-- Empire names
|
||||
--
|
||||
|
||||
CREATE TABLE naming.empire_names (
|
||||
id SERIAL NOT NULL PRIMARY KEY ,
|
||||
owner_id INT NOT NULL ,
|
||||
name VARCHAR(20) NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_empirenames_name
|
||||
ON naming.empire_names( lower(name) );
|
||||
CREATE INDEX idx_empirenames_owner
|
||||
ON naming.empire_names( owner_id );
|
||||
|
||||
ALTER TABLE naming.empire_names
|
||||
ADD CONSTRAINT fk_empirenames_owner
|
||||
FOREIGN KEY (owner_id) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
GRANT SELECT ON naming.empire_names TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Map names
|
||||
--
|
||||
CREATE TABLE naming.map_names(
|
||||
id SERIAL NOT NULL PRIMARY KEY ,
|
||||
name VARCHAR(20) NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_mapnames_name
|
||||
ON naming.map_names( lower(name) );
|
||||
|
||||
|
||||
--
|
||||
-- Changed map names
|
||||
--
|
||||
|
||||
CREATE TABLE naming.changed_map_names(
|
||||
name_id INT NOT NULL PRIMARY KEY ,
|
||||
named_by INT NOT NULL ,
|
||||
named_at TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_changedmapnames_namedby
|
||||
ON naming.changed_map_names (named_by);
|
||||
|
||||
ALTER TABLE naming.changed_map_names
|
||||
ADD CONSTRAINT fk_changedmapnames_name
|
||||
FOREIGN KEY (name_id) REFERENCES naming.map_names ,
|
||||
ADD CONSTRAINT fk_changedmapnames_namedby
|
||||
FOREIGN KEY (named_by) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Validated map names
|
||||
--
|
||||
|
||||
CREATE TABLE naming.validated_map_names(
|
||||
name_id INT NOT NULL PRIMARY KEY ,
|
||||
validated_by INT NOT NULL ,
|
||||
validated_at TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now()
|
||||
);
|
||||
|
||||
CREATE INDEX idx_validatedmapnames_namedby
|
||||
ON naming.validated_map_names (validated_by);
|
||||
|
||||
|
||||
ALTER TABLE naming.validated_map_names
|
||||
ADD CONSTRAINT fk_validatedmapnames_name
|
||||
FOREIGN KEY (name_id) REFERENCES naming.changed_map_names
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_validatedmapnames_validatedby
|
||||
FOREIGN KEY (validated_by) REFERENCES admin.administrators;
|
|
@ -0,0 +1,44 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- System "constants"
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
--
|
||||
-- Constant categories
|
||||
--
|
||||
CREATE TABLE sys.constant_categories(
|
||||
id SERIAL NOT NULL PRIMARY KEY ,
|
||||
name VARCHAR(64) NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_constantcategories_name
|
||||
ON sys.constant_categories (name);
|
||||
|
||||
|
||||
--
|
||||
-- Constant definitions and values
|
||||
--
|
||||
CREATE TABLE sys.constant_definitions(
|
||||
name VARCHAR(64) NOT NULL PRIMARY KEY,
|
||||
category_id INT NOT NULL ,
|
||||
description TEXT NOT NULL ,
|
||||
min_value REAL ,
|
||||
max_value REAL ,
|
||||
c_value REAL NOT NULL ,
|
||||
CHECK(
|
||||
( min_value IS NULL OR (
|
||||
min_value IS NOT NULL AND c_value >= min_value ) )
|
||||
AND ( max_value IS NULL OR (
|
||||
max_value IS NOT NULL AND max_value >= c_value ) )
|
||||
)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_constantdefinitions_category
|
||||
ON sys.constant_definitions (category_id);
|
||||
|
||||
ALTER TABLE sys.constant_definitions
|
||||
ADD CONSTRAINT fk_constraintdefinitions_category
|
||||
FOREIGN KEY (category_id) REFERENCES sys.constant_categories;
|
|
@ -0,0 +1,56 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Technology definitions
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Technology lines
|
||||
--
|
||||
|
||||
CREATE TABLE tech.lines(
|
||||
name_id INT NOT NULL PRIMARY KEY ,
|
||||
description_id INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_lines_description
|
||||
ON tech.lines (description_id);
|
||||
|
||||
ALTER TABLE tech.lines
|
||||
ADD CONSTRAINT fk_lines_name
|
||||
FOREIGN KEY (name_id) REFERENCES defs.strings ,
|
||||
ADD CONSTRAINT fk_lines_description
|
||||
FOREIGN KEY (description_id) REFERENCES defs.strings;
|
||||
|
||||
|
||||
--
|
||||
-- Technology levels
|
||||
--
|
||||
|
||||
CREATE TABLE tech.levels(
|
||||
id SERIAL NOT NULL PRIMARY KEY ,
|
||||
line_id INT NOT NULL ,
|
||||
level INT NOT NULL CHECK( level > 0 ) ,
|
||||
name_id INT NOT NULL ,
|
||||
description_id INT NOT NULL ,
|
||||
points INT NOT NULL CHECK( points > 0 ) ,
|
||||
cost INT NOT NULL CHECK( cost > 0 )
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_levels_linelevel
|
||||
ON tech.levels (line_id, level);
|
||||
CREATE INDEX idx_levels_name
|
||||
ON tech.levels (name_id);
|
||||
CREATE INDEX idx_levels_description
|
||||
ON tech.levels (description_id);
|
||||
|
||||
ALTER TABLE tech.levels
|
||||
ADD CONSTRAINT fk_levels_line
|
||||
FOREIGN KEY (line_id) REFERENCES tech.lines ,
|
||||
ADD CONSTRAINT fk_levels_name
|
||||
FOREIGN KEY (name_id) REFERENCES defs.strings ,
|
||||
ADD CONSTRAINT fk_levels_description
|
||||
FOREIGN KEY (description_id) REFERENCES defs.strings;
|
|
@ -0,0 +1,75 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Buildings/ships definitions
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
--
|
||||
-- "Buildables"
|
||||
--
|
||||
CREATE TABLE tech.buildables(
|
||||
name_id INT NOT NULL PRIMARY KEY ,
|
||||
description_id INT NOT NULL ,
|
||||
cost INT NOT NULL CHECK( cost > 0 ) ,
|
||||
work INT NOT NULL CHECK( work > 0 ) ,
|
||||
upkeep INT NOT NULL CHECK( upkeep >= 0 )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_buildables_description
|
||||
ON tech.buildables (description_id);
|
||||
|
||||
ALTER TABLE tech.buildables
|
||||
ADD CONSTRAINT fk_buildables_name
|
||||
FOREIGN KEY (name_id) REFERENCES defs.strings ,
|
||||
ADD CONSTRAINT fk_buildables_description
|
||||
FOREIGN KEY (description_id) REFERENCES defs.strings;
|
||||
|
||||
|
||||
--
|
||||
-- Requirements
|
||||
--
|
||||
CREATE TABLE tech.buildable_requirements(
|
||||
buildable_id INT NOT NULL ,
|
||||
level_id INT NOT NULL ,
|
||||
PRIMARY KEY( buildable_id , level_id )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_buildablereqs_level
|
||||
ON tech.buildable_requirements( level_id );
|
||||
|
||||
ALTER TABLE tech.buildable_requirements
|
||||
ADD CONSTRAINT fk_buildablereqs_buildable
|
||||
FOREIGN KEY (buildable_id) REFERENCES tech.buildables ,
|
||||
ADD CONSTRAINT fk_buildablereqs_level
|
||||
FOREIGN KEY (level_id) REFERENCES tech.levels;
|
||||
|
||||
|
||||
--
|
||||
-- Buildings
|
||||
--
|
||||
CREATE TABLE tech.buildings(
|
||||
buildable_id INT NOT NULL PRIMARY KEY ,
|
||||
workers INT NOT NULL CHECK( workers >= 0 ) ,
|
||||
output_type building_output_type ,
|
||||
output INT NOT NULL CHECK( output > 0 )
|
||||
);
|
||||
|
||||
ALTER TABLE tech.buildings
|
||||
ADD CONSTRAINT fk_buildings_buildable
|
||||
FOREIGN KEY (buildable_id) REFERENCES tech.buildables;
|
||||
|
||||
--
|
||||
-- Ships
|
||||
--
|
||||
CREATE TABLE tech.ships(
|
||||
buildable_id INT NOT NULL PRIMARY KEY ,
|
||||
flight_time INT NOT NULL CHECK( flight_time > 0 ) ,
|
||||
power INT NOT NULL CHECK( power > 0 )
|
||||
);
|
||||
|
||||
|
||||
ALTER TABLE tech.ships
|
||||
ADD CONSTRAINT fk_buildings_buildable
|
||||
FOREIGN KEY (buildable_id) REFERENCES tech.buildables;
|
|
@ -0,0 +1,95 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Stellar systems and planets
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Stellar systems
|
||||
--
|
||||
CREATE TABLE verse.systems(
|
||||
id SERIAL NOT NULL PRIMARY KEY ,
|
||||
x INT NOT NULL ,
|
||||
y INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_systems_coordinates
|
||||
ON verse.systems( x , y );
|
||||
|
||||
--
|
||||
-- Planets
|
||||
--
|
||||
CREATE TABLE verse.planets(
|
||||
name_id INT NOT NULL PRIMARY KEY ,
|
||||
system_id INT NOT NULL ,
|
||||
orbit INT NOT NULL
|
||||
CHECK( orbit BETWEEN 1 AND 5 ) ,
|
||||
picture INT NOT NULL ,
|
||||
population REAL NOT NULL
|
||||
CHECK( population >= 0 )
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_planets_coordinates
|
||||
ON verse.planets( system_id , orbit );
|
||||
|
||||
ALTER TABLE verse.planets
|
||||
ADD CONSTRAINT fk_planets_name
|
||||
FOREIGN KEY (name_id) REFERENCES naming.map_names ,
|
||||
ADD CONSTRAINT fk_planets_system
|
||||
FOREIGN KEY (system_id) REFERENCES verse.systems;
|
||||
|
||||
|
||||
--
|
||||
-- Happiness
|
||||
--
|
||||
CREATE TABLE verse.planet_happiness(
|
||||
planet_id INT NOT NULL PRIMARY KEY ,
|
||||
target REAL NOT NULL
|
||||
CHECK( target BETWEEN 0.0 AND 1.0 ) ,
|
||||
current REAL NOT NULL
|
||||
CHECK( current > 0 )
|
||||
);
|
||||
|
||||
ALTER TABLE verse.planet_happiness
|
||||
ADD CONSTRAINT fk_planethappiness_planet
|
||||
FOREIGN KEY (planet_id) REFERENCES verse.planets;
|
||||
|
||||
|
||||
--
|
||||
-- Money
|
||||
--
|
||||
CREATE TABLE verse.planet_money(
|
||||
planet_id INT NOT NULL PRIMARY KEY ,
|
||||
income REAL NOT NULL
|
||||
CHECK( income >= 0 ) ,
|
||||
upkeep REAL NOT NULL
|
||||
CHECK( upkeep >= 0 )
|
||||
);
|
||||
|
||||
ALTER TABLE verse.planet_money
|
||||
ADD CONSTRAINT fk_planetmoney_planet
|
||||
FOREIGN KEY (planet_id) REFERENCES verse.planets;
|
||||
|
||||
|
||||
--
|
||||
-- Buildings
|
||||
--
|
||||
CREATE TABLE verse.planet_buildings(
|
||||
planet_id INT NOT NULL ,
|
||||
building_id INT NOT NULL ,
|
||||
amount INT NOT NULL CHECK( amount >= 0 ) ,
|
||||
damage REAL NOT NULL CHECK( damage >= 0 ) ,
|
||||
PRIMARY KEY( planet_id , building_id )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_planetbuildings_building
|
||||
ON verse.planet_buildings (building_id);
|
||||
|
||||
ALTER TABLE verse.planet_buildings
|
||||
ADD CONSTRAINT fk_planetbuildings_planet
|
||||
FOREIGN KEY (planet_id) REFERENCES verse.planets ,
|
||||
ADD CONSTRAINT fk_planetbuildings_building
|
||||
FOREIGN KEY (building_id) REFERENCES tech.buildings;
|
|
@ -0,0 +1,176 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Empires and alliances
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Empires
|
||||
--
|
||||
|
||||
CREATE TABLE emp.empires(
|
||||
name_id INT NOT NULL PRIMARY KEY ,
|
||||
cash REAL NOT NULL
|
||||
CHECK( cash >= 0 ),
|
||||
debt REAL NOT NULL DEFAULT 0
|
||||
CHECK( debt >= 0)
|
||||
);
|
||||
|
||||
ALTER TABLE emp.empires
|
||||
ADD CONSTRAINT fk_empires_name
|
||||
FOREIGN KEY (name_id) REFERENCES naming.empire_names;
|
||||
|
||||
|
||||
--
|
||||
-- Empire technologies
|
||||
--
|
||||
|
||||
CREATE TABLE emp.technologies(
|
||||
empire_id INT NOT NULL ,
|
||||
line_id INT NOT NULL ,
|
||||
level INT NOT NULL DEFAULT 1
|
||||
CHECK( level > 0 ) ,
|
||||
accumulated REAL NOT NULL DEFAULT 0
|
||||
CHECK( accumulated >= 0 ),
|
||||
PRIMARY KEY( empire_id , line_id )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_technologies_line
|
||||
ON emp.technologies (line_id);
|
||||
|
||||
ALTER TABLE emp.technologies
|
||||
ADD CONSTRAINT fk_technologies_empire
|
||||
FOREIGN KEY (empire_id) REFERENCES emp.empires
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_technologies_line
|
||||
FOREIGN KEY (line_id) REFERENCES tech.lines;
|
||||
|
||||
|
||||
--
|
||||
-- Empire planets
|
||||
--
|
||||
|
||||
CREATE TABLE emp.planets(
|
||||
planet_id INT NOT NULL PRIMARY KEY ,
|
||||
empire_id INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_planets_empire
|
||||
ON emp.planets (empire_id);
|
||||
|
||||
ALTER TABLE emp.planets
|
||||
ADD CONSTRAINT fk_eplanets_planet
|
||||
FOREIGN KEY (planet_id) REFERENCES verse.planets ,
|
||||
ADD CONSTRAINT fk_eplanets_empire
|
||||
FOREIGN KEY (empire_id) REFERENCES emp.empires
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Planets being abandonned
|
||||
--
|
||||
|
||||
CREATE TABLE emp.abandon(
|
||||
planet_id INT NOT NULL PRIMARY KEY ,
|
||||
time_left INT NOT NULL CHECK ( time_left > 0 )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_abandon_ready
|
||||
ON emp.abandon ( ( time_left = 1 ) );
|
||||
|
||||
ALTER TABLE emp.abandon
|
||||
ADD CONSTRAINT fk_abandon_planet
|
||||
FOREIGN KEY (planet_id) REFERENCES emp.planets
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Alliances
|
||||
--
|
||||
|
||||
CREATE TABLE emp.alliances(
|
||||
id SERIAL NOT NULL PRIMARY KEY ,
|
||||
tag VARCHAR(5) NOT NULL ,
|
||||
name VARCHAR(128) NOT NULL ,
|
||||
leader_id INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_alliances_tag
|
||||
ON emp.alliances ( lower(tag) );
|
||||
CREATE UNIQUE INDEX idx_alliances_leader
|
||||
ON emp.alliances (leader_id);
|
||||
|
||||
ALTER TABLE emp.alliances
|
||||
ADD CONSTRAINT fk_alliances_leader
|
||||
FOREIGN KEY (leader_id) REFERENCES emp.empires
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Alliance membership
|
||||
--
|
||||
|
||||
CREATE TABLE emp.alliance_members(
|
||||
empire_id INT NOT NULL PRIMARY KEY ,
|
||||
alliance_id INT NOT NULL ,
|
||||
is_pending BOOLEAN NOT NULL
|
||||
DEFAULT TRUE
|
||||
);
|
||||
|
||||
CREATE INDEX idx_alliancemembers_alliance
|
||||
ON emp.alliance_members( alliance_id );
|
||||
|
||||
ALTER TABLE emp.alliance_members
|
||||
ADD CONSTRAINT fk_alliancemembers_empire
|
||||
FOREIGN KEY (empire_id) REFERENCES emp.empires
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_alliancemembers_alliance
|
||||
FOREIGN KEY (alliance_id) REFERENCES emp.alliances
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Enemy lists, alliances
|
||||
--
|
||||
|
||||
CREATE TABLE emp.enemy_alliances(
|
||||
empire_id INT NOT NULL ,
|
||||
alliance_id INT NOT NULL ,
|
||||
PRIMARY KEY (empire_id,alliance_id)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_enemyalliances_alliance
|
||||
ON emp.enemy_alliances (alliance_id);
|
||||
|
||||
ALTER TABLE emp.enemy_alliances
|
||||
ADD CONSTRAINT fk_enemyalliances_empire
|
||||
FOREIGN KEY (empire_id) REFERENCES emp.empires
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_enemyalliances_alliance
|
||||
FOREIGN KEY (alliance_id) REFERENCES emp.alliances
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Enemy lists, empires
|
||||
--
|
||||
|
||||
CREATE TABLE emp.enemy_empires(
|
||||
empire_id INT NOT NULL ,
|
||||
enemy_id INT NOT NULL ,
|
||||
PRIMARY KEY (empire_id,enemy_id)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_enemyempires_enemy
|
||||
ON emp.enemy_empires (enemy_id);
|
||||
|
||||
ALTER TABLE emp.enemy_empires
|
||||
ADD CONSTRAINT fk_enemyempires_empire
|
||||
FOREIGN KEY (empire_id) REFERENCES emp.empires
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_enemyempires_enemy
|
||||
FOREIGN KEY (enemy_id) REFERENCES emp.empires
|
||||
ON DELETE CASCADE;
|
|
@ -0,0 +1,82 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Construction queues
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Buildings queues
|
||||
--
|
||||
|
||||
CREATE TABLE verse.bld_queues(
|
||||
planet_id INT NOT NULL PRIMARY KEY ,
|
||||
money REAL NOT NULL CHECK( money >= 0 ),
|
||||
work REAL NOT NULL CHECK( work >= 0 )
|
||||
);
|
||||
|
||||
ALTER TABLE verse.bld_queues
|
||||
ADD CONSTRAINT fk_bldqueues_planet
|
||||
FOREIGN KEY (planet_id) REFERENCES verse.planets;
|
||||
|
||||
|
||||
--
|
||||
-- Buildings queue items
|
||||
--
|
||||
|
||||
CREATE TABLE verse.bld_items(
|
||||
queue_id INT NOT NULL ,
|
||||
queue_order INT NOT NULL CHECK( queue_order >= 0 ) ,
|
||||
building_id INT NOT NULL ,
|
||||
destroy BOOLEAN NOT NULL ,
|
||||
amount INT NOT NULL CHECK( amount > 0 ) ,
|
||||
PRIMARY KEY( queue_id , queue_order )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_blditems_building
|
||||
ON verse.bld_items (building_id);
|
||||
|
||||
ALTER TABLE verse.bld_items
|
||||
ADD CONSTRAINT fk_blditems_queue
|
||||
FOREIGN KEY (queue_id) REFERENCES verse.bld_queues ,
|
||||
ADD CONSTRAINT fk_blditems_building
|
||||
FOREIGN KEY (building_id) REFERENCES tech.buildings;
|
||||
|
||||
|
||||
--
|
||||
-- Military queues
|
||||
--
|
||||
|
||||
CREATE TABLE verse.mil_queues(
|
||||
planet_id INT NOT NULL PRIMARY KEY ,
|
||||
money REAL NOT NULL CHECK( money >= 0 ),
|
||||
work REAL NOT NULL CHECK( work >= 0 )
|
||||
);
|
||||
|
||||
ALTER TABLE verse.mil_queues
|
||||
ADD CONSTRAINT fk_milqueues_planet
|
||||
FOREIGN KEY (planet_id) REFERENCES verse.planets;
|
||||
|
||||
|
||||
--
|
||||
-- Military queue items
|
||||
--
|
||||
|
||||
CREATE TABLE verse.mil_items(
|
||||
queue_id INT NOT NULL ,
|
||||
queue_order INT NOT NULL CHECK( queue_order >= 0 ) ,
|
||||
ship_id INT NOT NULL ,
|
||||
amount INT NOT NULL CHECK( amount > 0 ) ,
|
||||
PRIMARY KEY( queue_id , queue_order )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_militems_ship
|
||||
ON verse.mil_items (ship_id);
|
||||
|
||||
ALTER TABLE verse.mil_items
|
||||
ADD CONSTRAINT fk_militems_queue
|
||||
FOREIGN KEY (queue_id) REFERENCES verse.mil_queues ,
|
||||
ADD CONSTRAINT fk_militems_ship
|
||||
FOREIGN KEY (ship_id) REFERENCES tech.ships;
|
|
@ -0,0 +1,118 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Fleets
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Fleets
|
||||
--
|
||||
|
||||
CREATE TABLE fleets.fleets(
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY ,
|
||||
owner_id INT NOT NULL ,
|
||||
location_id INT NOT NULL ,
|
||||
name VARCHAR(64) ,
|
||||
attacking BOOLEAN NOT NULL ,
|
||||
status fleet_status NOT NULL ,
|
||||
penalty INT NOT NULL ,
|
||||
CHECK( ( status = 'AVAILABLE' AND penalty = 0 )
|
||||
OR ( status <> 'AVAILABLE' AND penalty > 0) )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_fleets_owner
|
||||
ON fleets.fleets ( owner_id );
|
||||
CREATE INDEX idx_fleets_location
|
||||
ON fleets.fleets ( location_id );
|
||||
CREATE INDEX idx_fleets_status
|
||||
ON fleets.fleets ( status , penalty );
|
||||
|
||||
ALTER TABLE fleets.fleets
|
||||
ADD CONSTRAINT fk_fleets_owner
|
||||
FOREIGN KEY ( owner_id ) REFERENCES emp.empires
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_fleets_location
|
||||
FOREIGN KEY ( location_id ) REFERENCES verse.planets;
|
||||
|
||||
|
||||
--
|
||||
-- Ships
|
||||
--
|
||||
|
||||
CREATE TABLE fleets.ships(
|
||||
fleet_id BIGINT NOT NULL ,
|
||||
ship_id INT NOT NULL ,
|
||||
amount INT NOT NULL CHECK( amount >= 0 ) ,
|
||||
damage REAL NOT NULL ,
|
||||
PRIMARY KEY( fleet_id , ship_id )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_ships_ship
|
||||
ON fleets.ships( ship_id );
|
||||
|
||||
ALTER TABLE fleets.ships
|
||||
ADD CONSTRAINT fk_ships_fleet
|
||||
FOREIGN KEY ( fleet_id ) REFERENCES fleets.fleets
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_ships_ship
|
||||
FOREIGN KEY ( ship_id ) REFERENCES tech.ships;
|
||||
|
||||
|
||||
--
|
||||
-- Fleet movements
|
||||
--
|
||||
|
||||
CREATE TABLE fleets.movements(
|
||||
fleet_id BIGINT NOT NULL PRIMARY KEY ,
|
||||
source_id INT NOT NULL ,
|
||||
time_left INT NOT NULL CHECK( time_left > 0 ) ,
|
||||
state_time_left INT NOT NULL CHECK( state_time_left > 0 )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_movements_source
|
||||
ON fleets.movements( source_id );
|
||||
|
||||
ALTER TABLE fleets.movements
|
||||
ADD CONSTRAINT fk_movements_fleet
|
||||
FOREIGN KEY ( fleet_id ) REFERENCES fleets.fleets
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_movements_source
|
||||
FOREIGN KEY ( source_id ) REFERENCES verse.planets;
|
||||
|
||||
|
||||
--
|
||||
-- Movement states, outer space
|
||||
--
|
||||
|
||||
CREATE TABLE fleets.ms_space(
|
||||
movement_id BIGINT NOT NULL PRIMARY KEY ,
|
||||
start_x REAL NOT NULL ,
|
||||
start_y REAL NOT NULL
|
||||
);
|
||||
|
||||
ALTER TABLE fleets.ms_space
|
||||
ADD CONSTRAINT fk_msspace_movement
|
||||
FOREIGN KEY ( movement_id ) REFERENCES fleets.movements
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Movement states, in system
|
||||
--
|
||||
|
||||
CREATE TABLE fleets.ms_system(
|
||||
movement_id BIGINT NOT NULL PRIMARY KEY ,
|
||||
ref_point_id INT NOT NULL ,
|
||||
outwards BOOLEAN NOT NULL ,
|
||||
past_ref_point BOOLEAN NOT NULL
|
||||
);
|
||||
|
||||
ALTER TABLE fleets.ms_system
|
||||
ADD CONSTRAINT fk_mssystem_movement
|
||||
FOREIGN KEY ( movement_id ) REFERENCES fleets.movements
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_mssystem_refpoint
|
||||
FOREIGN KEY ( ref_point_id ) REFERENCES verse.planets;
|
|
@ -0,0 +1,107 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- System & game updates status
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
--
|
||||
-- System status
|
||||
--
|
||||
CREATE TABLE sys.status(
|
||||
next_tick BIGINT NOT NULL
|
||||
DEFAULT 0 ,
|
||||
current_tick BIGINT ,
|
||||
|
||||
last_msg_recap TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( ) ,
|
||||
last_admin_recap TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( ) ,
|
||||
last_error_recap TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( ) ,
|
||||
|
||||
maintenance_start TIMESTAMP WITHOUT TIME ZONE ,
|
||||
maintenance_end TIMESTAMP WITHOUT TIME ZONE ,
|
||||
maintenance_text TEXT
|
||||
);
|
||||
|
||||
INSERT INTO sys.status DEFAULT VALUES;
|
||||
|
||||
GRANT SELECT ON sys.status TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Ticker status
|
||||
--
|
||||
|
||||
CREATE TYPE ticker_task_status
|
||||
AS ENUM( 'RUNNING' , 'STOPPED' , 'AUTO' );
|
||||
|
||||
CREATE TABLE sys.ticker(
|
||||
id SERIAL PRIMARY KEY ,
|
||||
task_name VARCHAR(64) NOT NULL UNIQUE ,
|
||||
status ticker_task_status NOT NULL ,
|
||||
auto_start TIMESTAMP WITHOUT TIME ZONE
|
||||
);
|
||||
|
||||
INSERT INTO sys.ticker( task_name , status )
|
||||
VALUES ( 'Game update' , 'STOPPED' );
|
||||
|
||||
GRANT SELECT ON sys.ticker TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Updates
|
||||
--
|
||||
CREATE TABLE sys.updates(
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY ,
|
||||
gu_type update_type NOT NULL ,
|
||||
status processing_status NOT NULL DEFAULT 'FUTURE' ,
|
||||
last_tick BIGINT NOT NULL DEFAULT -1
|
||||
);
|
||||
|
||||
CREATE INDEX idx_updates_finder
|
||||
ON sys.updates (gu_type, status, last_tick);
|
||||
|
||||
|
||||
--
|
||||
-- Planet updates
|
||||
--
|
||||
CREATE TABLE verse.updates(
|
||||
update_id BIGINT NOT NULL PRIMARY KEY ,
|
||||
planet_id INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_planetupdates_planet
|
||||
ON verse.updates (planet_id);
|
||||
|
||||
ALTER TABLE verse.updates
|
||||
ADD CONSTRAINT fk_planetupdates_update
|
||||
FOREIGN KEY ( update_id ) REFERENCES sys.updates ,
|
||||
ADD CONSTRAINT fk_planetupdates_planet
|
||||
FOREIGN KEY ( planet_id ) REFERENCES verse.planets;
|
||||
|
||||
|
||||
--
|
||||
-- Empire updates
|
||||
--
|
||||
CREATE TABLE emp.updates(
|
||||
update_id BIGINT NOT NULL PRIMARY KEY ,
|
||||
empire_id INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_empireupdates_empire
|
||||
ON emp.updates( empire_id );
|
||||
|
||||
ALTER TABLE emp.updates
|
||||
ADD CONSTRAINT fk_empireupdates_update
|
||||
FOREIGN KEY ( update_id ) REFERENCES sys.updates ,
|
||||
ADD CONSTRAINT fk_empireupdates_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE CASCADE;
|
|
@ -0,0 +1,126 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- System, user and administrative logs
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- System logs
|
||||
--
|
||||
CREATE TABLE sys.logs(
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY ,
|
||||
t TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( ) ,
|
||||
component VARCHAR( 64 ) ,
|
||||
level log_level NOT NULL ,
|
||||
message TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_syslogs_time
|
||||
ON sys.logs( t );
|
||||
CREATE INDEX idx_syslogs_component
|
||||
ON sys.logs( component );
|
||||
CREATE INDEX idx_syslogs_level
|
||||
ON sys.logs( level );
|
||||
|
||||
GRANT SELECT ON sys.logs TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- System logs, exceptions
|
||||
--
|
||||
CREATE TABLE sys.exceptions(
|
||||
id BIGSERIAL NOT NULL PRIMARY KEY ,
|
||||
log_id BIGINT NOT NULL ,
|
||||
depth INT NOT NULL CHECK( depth>= 0 ) ,
|
||||
exc_class VARCHAR( 255 ) NOT NULL ,
|
||||
message TEXT
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_exceptions_logdepth
|
||||
ON sys.exceptions (log_id , depth );
|
||||
|
||||
ALTER TABLE sys.exceptions
|
||||
ADD CONSTRAINT fk_exceptions_log
|
||||
FOREIGN KEY ( log_id ) REFERENCES sys.logs
|
||||
ON DELETE CASCADE;
|
||||
|
||||
GRANT SELECT ON sys.exceptions TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- System logs, stack traces
|
||||
--
|
||||
CREATE TABLE sys.stack_traces(
|
||||
exception_id BIGSERIAL NOT NULL ,
|
||||
depth INT NOT NULL ,
|
||||
location TEXT ,
|
||||
file_name TEXT ,
|
||||
line_number INT ,
|
||||
PRIMARY KEY( exception_id , depth )
|
||||
);
|
||||
|
||||
ALTER TABLE sys.stack_traces
|
||||
ADD CONSTRAINT fk_stacktraces_exception
|
||||
FOREIGN KEY ( exception_id ) REFERENCES sys.exceptions
|
||||
ON DELETE CASCADE;
|
||||
|
||||
GRANT SELECT ON sys.stack_traces TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- User logs
|
||||
--
|
||||
CREATE TABLE users.logs(
|
||||
t TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( ) ,
|
||||
credentials_id INT NOT NULL ,
|
||||
level log_level NOT NULL ,
|
||||
message TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_userlogs_time
|
||||
ON users.logs( t );
|
||||
CREATE INDEX idx_userlogs_level
|
||||
ON users.logs( level );
|
||||
CREATE INDEX idx_userlogs_account
|
||||
ON users.logs( credentials_id );
|
||||
|
||||
ALTER TABLE users.logs
|
||||
ADD CONSTRAINT fk_userlogs_credentials
|
||||
FOREIGN KEY (credentials_id) REFERENCES users.credentials
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
||||
|
||||
GRANT SELECT ON users.logs TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Administrative logs
|
||||
--
|
||||
CREATE TABLE admin.logs(
|
||||
t TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now( ) ,
|
||||
admin_id INT NOT NULL ,
|
||||
level log_level NOT NULL ,
|
||||
message TEXT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_adminlogs_time
|
||||
ON admin.logs( t );
|
||||
CREATE INDEX idx_adminlogs_level
|
||||
ON admin.logs( level );
|
||||
CREATE INDEX idx_adminlogs_admin
|
||||
ON admin.logs( admin_id );
|
||||
|
||||
ALTER TABLE admin.logs
|
||||
ADD CONSTRAINT fk_userlogs_admin
|
||||
FOREIGN KEY (admin_id) REFERENCES admin.administrators;
|
||||
|
||||
|
||||
GRANT SELECT ON admin.logs TO :dbuser;
|
|
@ -0,0 +1,230 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Battles
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Status change types
|
||||
--
|
||||
|
||||
CREATE TYPE battle_planet_change
|
||||
AS ENUM( 'INIT' , 'RENAME', 'BUILD' , 'DESTROY' , 'BATTLE' );
|
||||
CREATE TYPE battle_fleet_change
|
||||
AS ENUM( 'INIT' , 'BUILD', 'ARRIVE' , 'DEPART' , 'DISBAND' , 'BATTLE' );
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Main battle table
|
||||
--
|
||||
|
||||
CREATE TABLE battles.battles(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
location_id INT NOT NULL ,
|
||||
first_tick BIGINT NOT NULL ,
|
||||
last_tick BIGINT
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_battles_uniqueness
|
||||
ON battles.battles( location_id , last_tick );
|
||||
|
||||
ALTER TABLE battles.battles
|
||||
ADD CONSTRAINT fk_battles_location
|
||||
FOREIGN KEY ( location_id ) REFERENCES verse.planets;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Battle planet status
|
||||
--
|
||||
|
||||
CREATE TABLE battles.planets(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
battle_id BIGINT NOT NULL ,
|
||||
tick_identifier BIGINT NOT NULL ,
|
||||
change_type battle_planet_change NOT NULL ,
|
||||
name VARCHAR(20)
|
||||
);
|
||||
|
||||
CREATE INDEX idx_planets_tick
|
||||
ON battles.planets( tick_identifier );
|
||||
|
||||
CREATE UNIQUE INDEX idx_planets_uniquenes
|
||||
ON battles.planets( battle_id , tick_identifier , change_type );
|
||||
|
||||
ALTER TABLE battles.planets
|
||||
ADD CONSTRAINT fk_planets_battle
|
||||
FOREIGN KEY ( battle_id ) REFERENCES battles.battles
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Battle buildings
|
||||
--
|
||||
|
||||
CREATE TABLE battles.buildings(
|
||||
planet_id BIGINT NOT NULL ,
|
||||
building_id INT NOT NULL ,
|
||||
change INT NOT NULL CHECK( change <> 0 ) ,
|
||||
PRIMARY KEY( planet_id , building_id )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_buildings_building
|
||||
ON battles.buildings ( building_id );
|
||||
|
||||
ALTER TABLE battles.buildings
|
||||
ADD CONSTRAINT fk_buildings_planet
|
||||
FOREIGN KEY ( planet_id ) REFERENCES battles.planets
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_buildings_building
|
||||
FOREIGN KEY ( building_id ) REFERENCES tech.buildings;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Battle - planetary defence power
|
||||
--
|
||||
|
||||
CREATE TABLE battles.defences(
|
||||
battle_id BIGINT NOT NULL ,
|
||||
tick_identifier BIGINT NOT NULL ,
|
||||
power BIGINT NOT NULL ,
|
||||
PRIMARY KEY( battle_id , tick_identifier )
|
||||
);
|
||||
|
||||
ALTER TABLE battles.defences
|
||||
ADD CONSTRAINT fk_defences_battle
|
||||
FOREIGN KEY ( battle_id ) REFERENCES battles.battles
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Empires involved in a battle
|
||||
--
|
||||
|
||||
CREATE TABLE battles.empires(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
name VARCHAR(20) NOT NULL ,
|
||||
empire_id INT
|
||||
);
|
||||
|
||||
CREATE INDEX idx_empires_name
|
||||
ON battles.empires( name );
|
||||
|
||||
CREATE INDEX idx_empires_empire
|
||||
ON battles.empires( empire_id );
|
||||
|
||||
ALTER TABLE battles.empires
|
||||
ADD CONSTRAINT fk_empires_empire
|
||||
FOREIGN KEY (empire_id) REFERENCES emp.empires
|
||||
ON DELETE SET NULL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Protagonists
|
||||
--
|
||||
|
||||
CREATE TABLE battles.protagonists(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
battle_id BIGINT NOT NULL ,
|
||||
empire_id BIGINT NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_protagonists_uniqueness
|
||||
ON battles.protagonists( battle_id , empire_id );
|
||||
|
||||
CREATE INDEX idx_protagonists_empire
|
||||
ON battles.protagonists( empire_id );
|
||||
|
||||
ALTER TABLE battles.protagonists
|
||||
ADD CONSTRAINT fk_protagonists_battle
|
||||
FOREIGN KEY (battle_id) REFERENCES battles.battles
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_protagonists_empire
|
||||
FOREIGN KEY (empire_id) REFERENCES battles.empires;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Planet ownership
|
||||
--
|
||||
|
||||
CREATE TABLE battles.planet_ownership(
|
||||
protagonist_id BIGINT NOT NULL PRIMARY KEY ,
|
||||
abandoned_at BIGINT
|
||||
);
|
||||
|
||||
ALTER TABLE battles.planet_ownership
|
||||
ADD CONSTRAINT fk_ownership_protagonist
|
||||
FOREIGN KEY (protagonist_id) REFERENCES battles.protagonists
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Battle status changes
|
||||
--
|
||||
|
||||
CREATE TABLE battles.status_changes(
|
||||
protagonist_id BIGINT NOT NULL ,
|
||||
tick_identifier BIGINT NOT NULL ,
|
||||
attacking BOOLEAN NOT NULL ,
|
||||
PRIMARY KEY( protagonist_id , tick_identifier )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_statuschanges_tick
|
||||
ON battles.status_changes( tick_identifier );
|
||||
|
||||
ALTER TABLE battles.status_changes
|
||||
ADD CONSTRAINT fk_statuschanges_protagonist
|
||||
FOREIGN KEY (protagonist_id) REFERENCES battles.protagonists
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Fleets involved in battles
|
||||
--
|
||||
|
||||
CREATE TABLE battles.fleets(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
protagonist_id BIGINT NOT NULL ,
|
||||
tick_identifier BIGINT NOT NULL ,
|
||||
change_type battle_fleet_change NOT NULL
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_fleets_uniqueness
|
||||
ON battles.fleets( protagonist_id , tick_identifier , change_type );
|
||||
CREATE INDEX idx_fleets_tick
|
||||
ON battles.fleets( tick_identifier );
|
||||
|
||||
ALTER TABLE battles.fleets
|
||||
ADD CONSTRAINT fk_fleets_protagonist
|
||||
FOREIGN KEY (protagonist_id) REFERENCES battles.protagonists
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Ships in battle fleets
|
||||
--
|
||||
|
||||
CREATE TABLE battles.ships(
|
||||
fleet_id BIGINT NOT NULL ,
|
||||
ship_id INT NOT NULL ,
|
||||
change INT NOT NULL CHECK( change <> 0 )
|
||||
);
|
||||
|
||||
ALTER TABLE battles.ships
|
||||
ADD CONSTRAINT fk_ships_fleet
|
||||
FOREIGN KEY ( fleet_id ) REFERENCES battles.fleets
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_ships_ship
|
||||
FOREIGN KEY ( ship_id ) REFERENCES tech.ships;
|
|
@ -0,0 +1,311 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Storage of events (internal messages)
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TYPE event_type
|
||||
AS ENUM ( 'QUEUE' , 'EMPIRE' , 'FLEETS' , 'PLANET', 'ALLIANCE', 'ADMIN' , 'BUGS' );
|
||||
|
||||
CREATE TYPE event_status
|
||||
AS ENUM( 'TICK' , 'ACTION' , 'READY' , 'SENT' );
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Events table
|
||||
--
|
||||
|
||||
CREATE TABLE events.events(
|
||||
event_id BIGSERIAL PRIMARY KEY ,
|
||||
empire_id INT NOT NULL ,
|
||||
tick BIGINT NOT NULL ,
|
||||
real_time TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL
|
||||
DEFAULT now() ,
|
||||
evt_type event_type NOT NULL ,
|
||||
evt_subtype INT NOT NULL ,
|
||||
status event_status NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_events_empire
|
||||
ON events.events (empire_id);
|
||||
|
||||
CREATE INDEX idx_events_time
|
||||
ON events.events (real_time);
|
||||
|
||||
CREATE INDEX idx_events_lookup
|
||||
ON events.events( empire_id , tick , evt_type , evt_subtype , status )
|
||||
WHERE status IN ( 'TICK' , 'ACTION' );
|
||||
|
||||
ALTER TABLE events.events
|
||||
ADD CONSTRAINT fk_events_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE CASCADE;
|
||||
|
||||
GRANT SELECT ON events.events TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Build queue events
|
||||
--
|
||||
|
||||
CREATE TABLE events.queue_events (
|
||||
event_id BIGINT NOT NULL PRIMARY KEY
|
||||
);
|
||||
|
||||
ALTER TABLE events.queue_events
|
||||
ADD CONSTRAINT fk_bqevents_event
|
||||
FOREIGN KEY (event_id) REFERENCES events.events
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Build queue event locations
|
||||
--
|
||||
|
||||
CREATE TABLE events.bqe_locations(
|
||||
event_id BIGINT NOT NULL ,
|
||||
location_id INT NOT NULL ,
|
||||
location_name VARCHAR(20) NOT NULL ,
|
||||
PRIMARY KEY( event_id , location_id )
|
||||
);
|
||||
|
||||
ALTER TABLE events.bqe_locations
|
||||
ADD CONSTRAINT fk_bqelocations_event
|
||||
FOREIGN KEY (event_id) REFERENCES events.queue_events
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_bqelocations_location
|
||||
FOREIGN KEY (location_id) REFERENCES verse.planets;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Empire events
|
||||
--
|
||||
|
||||
CREATE TABLE events.empire_events(
|
||||
event_id BIGINT NOT NULL PRIMARY KEY ,
|
||||
technology_id INT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_empevents_tech
|
||||
ON events.empire_events (technology_id);
|
||||
|
||||
ALTER TABLE events.empire_events
|
||||
ADD CONSTRAINT fk_empevents_event
|
||||
FOREIGN KEY (event_id) REFERENCES events.events
|
||||
ON DELETE CASCADE,
|
||||
ADD CONSTRAINT fk_empevents_tech
|
||||
FOREIGN KEY (technology_id) REFERENCES tech.levels;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Fleet events
|
||||
--
|
||||
|
||||
CREATE TABLE events.fleets_events(
|
||||
event_id BIGINT NOT NULL PRIMARY KEY ,
|
||||
location_id INT NOT NULL ,
|
||||
location_name VARCHAR(20) NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_flevents_location
|
||||
ON events.fleets_events( location_id );
|
||||
|
||||
ALTER TABLE events.fleets_events
|
||||
ADD CONSTRAINT fk_flevents_event
|
||||
FOREIGN KEY (event_id) REFERENCES events.events
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_flevents_location
|
||||
FOREIGN KEY (location_id) REFERENCES verse.planets;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Fleets for fleet events
|
||||
--
|
||||
|
||||
CREATE TABLE events.fleet_lists(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
event_id BIGINT NOT NULL ,
|
||||
owner_id INT ,
|
||||
owner_name VARCHAR(20) NOT NULL ,
|
||||
fleet_name VARCHAR(64) ,
|
||||
fleet_power BIGINT NOT NULL CHECK( fleet_power > 0 ) ,
|
||||
status BOOLEAN ,
|
||||
source_id INT ,
|
||||
source_name VARCHAR(20) ,
|
||||
CHECK( source_id IS NULL AND source_name IS NULL OR source_id IS NOT NULL AND source_name IS NOT NULL )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_flelists_event
|
||||
ON events.fleet_lists( event_id );
|
||||
|
||||
CREATE INDEX idx_flelists_owner
|
||||
ON events.fleet_lists( owner_id )
|
||||
WHERE owner_id IS NOT NULL;
|
||||
|
||||
CREATE INDEX idx_flelists_source
|
||||
ON events.fleet_lists( source_id )
|
||||
WHERE source_id IS NOT NULL;
|
||||
|
||||
ALTER TABLE events.fleet_lists
|
||||
ADD CONSTRAINT fk_flelist_event
|
||||
FOREIGN KEY ( event_id ) REFERENCES events.fleets_events
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_flelist_owner
|
||||
FOREIGN KEY ( owner_id ) REFERENCES emp.empires
|
||||
ON DELETE SET NULL ,
|
||||
ADD CONSTRAINT fk_flelist_source
|
||||
FOREIGN KEY ( source_id ) REFERENCES verse.planets;
|
||||
|
||||
GRANT SELECT ON events.fleet_lists TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Planet events
|
||||
--
|
||||
|
||||
CREATE TABLE events.planet_events(
|
||||
event_id BIGINT PRIMARY KEY,
|
||||
location_id INT NOT NULL ,
|
||||
location_name VARCHAR(20) NOT NULL ,
|
||||
empire_id INT ,
|
||||
empire_name VARCHAR(20) ,
|
||||
battle_id BIGINT ,
|
||||
CHECK( battle_id IS NULL AND empire_id IS NULL AND empire_name IS NULL
|
||||
OR battle_id IS NOT NULL AND empire_id IS NULL AND empire_name IS NULL
|
||||
OR battle_id IS NULL AND empire_name IS NOT NULL )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_pevents_event
|
||||
ON events.planet_events ( event_id );
|
||||
|
||||
CREATE INDEX idx_pevents_location
|
||||
ON events.planet_events ( location_id );
|
||||
|
||||
CREATE INDEX idx_pevents_empire
|
||||
ON events.planet_events ( empire_id )
|
||||
WHERE empire_id IS NOT NULL;
|
||||
|
||||
CREATE INDEX idx_pevents_battle
|
||||
ON events.planet_events ( battle_id )
|
||||
WHERE battle_id IS NOT NULL;
|
||||
|
||||
ALTER TABLE events.planet_events
|
||||
ADD CONSTRAINT fk_pevents_event
|
||||
FOREIGN KEY ( event_id ) REFERENCES events.events
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_pevents_location
|
||||
FOREIGN KEY ( location_id ) REFERENCES verse.planets ,
|
||||
ADD CONSTRAINT fk_pevents_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE SET NULL ,
|
||||
ADD CONSTRAINT fk_pevents_battle
|
||||
FOREIGN KEY ( battle_id ) REFERENCES battles.battles;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Alliance events
|
||||
--
|
||||
|
||||
CREATE TABLE events.alliance_events(
|
||||
event_id BIGINT PRIMARY KEY ,
|
||||
alliance_id INT ,
|
||||
alliance_tag VARCHAR( 5 ) NOT NULL ,
|
||||
empire_id INT ,
|
||||
empire_name VARCHAR( 20 ) ,
|
||||
req_result BOOLEAN ,
|
||||
CHECK( req_result IS NULL AND empire_id IS NULL AND empire_name IS NULL
|
||||
OR req_result IS NOT NULL AND empire_id IS NULL AND empire_name IS NULL
|
||||
OR req_result IS NULL AND empire_name IS NOT NULL )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_aevents_event
|
||||
ON events.alliance_events ( event_id );
|
||||
|
||||
CREATE INDEX idx_aevents_alliance
|
||||
ON events.alliance_events ( alliance_id )
|
||||
WHERE alliance_id IS NOT NULL;
|
||||
|
||||
CREATE INDEX idx_aevents_empire
|
||||
ON events.alliance_events ( empire_id )
|
||||
WHERE empire_id IS NOT NULL;
|
||||
|
||||
ALTER TABLE events.alliance_events
|
||||
ADD CONSTRAINT fk_aevents_event
|
||||
FOREIGN KEY ( event_id ) REFERENCES events.events
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_aevents_allliance
|
||||
FOREIGN KEY ( alliance_id ) REFERENCES emp.alliances
|
||||
ON DELETE SET NULL ,
|
||||
ADD CONSTRAINT fk_aevents_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE SET NULL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Admin events
|
||||
--
|
||||
|
||||
CREATE TABLE events.admin_events(
|
||||
event_id BIGINT PRIMARY KEY ,
|
||||
n_warnings INT ,
|
||||
location_id INT ,
|
||||
old_name VARCHAR( 20 ) NOT NULL ,
|
||||
new_name VARCHAR( 20 )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_adevents_event
|
||||
ON events.admin_events ( event_id );
|
||||
|
||||
CREATE INDEX idx_adevents_location
|
||||
ON events.admin_events ( location_id )
|
||||
WHERE location_id IS NOT NULL;
|
||||
|
||||
ALTER TABLE events.admin_events
|
||||
ADD CONSTRAINT fk_adevents_event
|
||||
FOREIGN KEY ( event_id ) REFERENCES events.events
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_adevents_location
|
||||
FOREIGN KEY ( location_id ) REFERENCES verse.planets;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Bug tracking events
|
||||
--
|
||||
|
||||
CREATE TABLE events.bug_events(
|
||||
event_id BIGINT PRIMARY KEY ,
|
||||
bug_id BIGINT NOT NULL ,
|
||||
submitter_id BIGINT NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_btevents_event
|
||||
ON events.bug_events ( event_id );
|
||||
|
||||
CREATE INDEX idx_btevents_bug
|
||||
ON events.bug_events ( bug_id );
|
||||
|
||||
CREATE INDEX idx_btevents_submitter
|
||||
ON events.bug_events ( submitter_id );
|
||||
|
||||
|
||||
ALTER TABLE events.bug_events
|
||||
ADD CONSTRAINT fk_btevents_event
|
||||
FOREIGN KEY ( event_id ) REFERENCES events.events
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_btevents_bug
|
||||
FOREIGN KEY ( bug_id ) REFERENCES bugs.initial_report_events ,
|
||||
ADD CONSTRAINT fk_btevents_submitter
|
||||
FOREIGN KEY ( submitter_id ) REFERENCES bugs.submitters;
|
|
@ -0,0 +1,235 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Storage of messages
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE TYPE sender_type
|
||||
AS ENUM( 'ADM', 'EMP' );
|
||||
|
||||
CREATE TYPE receiver_type
|
||||
AS ENUM( 'ADM' , 'EMP' , 'ALL' );
|
||||
|
||||
CREATE TYPE message_status
|
||||
AS ENUM( 'UNREAD' , 'READ' , 'DELETED' );
|
||||
|
||||
|
||||
--
|
||||
-- Message senders
|
||||
--
|
||||
|
||||
CREATE TABLE msgs.senders(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
sender_type sender_type NOT NULL ,
|
||||
name VARCHAR(48) NOT NULL ,
|
||||
empire_id INT ,
|
||||
admin_id INT ,
|
||||
CHECK ( empire_id IS NULL AND admin_id IS NULL
|
||||
OR sender_type = 'ADM' AND empire_id IS NULL AND admin_id IS NOT NULL
|
||||
OR sender_type = 'EMP' AND empire_id IS NOT NULL AND admin_id IS NULL )
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_senders_empires
|
||||
ON msgs.senders ( empire_id )
|
||||
WHERE empire_id IS NOT NULL;
|
||||
|
||||
CREATE UNIQUE INDEX idx_senders_admins
|
||||
ON msgs.senders ( admin_id )
|
||||
WHERE admin_id IS NOT NULL;
|
||||
|
||||
ALTER TABLE msgs.senders
|
||||
ADD CONSTRAINT fk_senders_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE SET NULL ,
|
||||
ADD CONSTRAINT fk_senders_admin
|
||||
FOREIGN KEY ( admin_id ) REFERENCES admin.administrators
|
||||
ON DELETE SET NULL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Message receivers
|
||||
--
|
||||
|
||||
CREATE TABLE msgs.receivers(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
receiver_type receiver_type NOT NULL ,
|
||||
name VARCHAR(48) NOT NULL ,
|
||||
empire_id INT ,
|
||||
admin_id INT ,
|
||||
alliance_id INT ,
|
||||
CHECK ( empire_id IS NULL AND admin_id IS NULL AND alliance_id IS NULL
|
||||
OR receiver_type = 'ADM' AND empire_id IS NULL AND admin_id IS NOT NULL AND alliance_id IS NULL
|
||||
OR receiver_type = 'EMP' AND empire_id IS NOT NULL AND admin_id IS NULL AND alliance_id IS NULL
|
||||
OR receiver_type = 'ALL' AND empire_id IS NULL AND admin_id IS NULL AND alliance_id IS NOT NULL )
|
||||
);
|
||||
|
||||
CREATE UNIQUE INDEX idx_receivers_empires
|
||||
ON msgs.receivers ( empire_id )
|
||||
WHERE empire_id IS NOT NULL;
|
||||
|
||||
CREATE UNIQUE INDEX idx_receivers_admins
|
||||
ON msgs.receivers ( admin_id )
|
||||
WHERE admin_id IS NOT NULL;
|
||||
|
||||
CREATE UNIQUE INDEX idx_receivers_alliances
|
||||
ON msgs.receivers ( alliance_id )
|
||||
WHERE alliance_id IS NOT NULL;
|
||||
|
||||
ALTER TABLE msgs.receivers
|
||||
ADD CONSTRAINT fk_receivers_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE SET NULL ,
|
||||
ADD CONSTRAINT fk_receivers_alliance
|
||||
FOREIGN KEY ( alliance_id ) REFERENCES emp.alliances
|
||||
ON DELETE SET NULL ,
|
||||
ADD CONSTRAINT fk_receivers_admin
|
||||
FOREIGN KEY ( admin_id ) REFERENCES admin.administrators
|
||||
ON DELETE SET NULL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Text messages
|
||||
--
|
||||
|
||||
CREATE TABLE msgs.text_messages(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
tick BIGINT NOT NULL ,
|
||||
t TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL DEFAULT now( ) ,
|
||||
title VARCHAR( 64 ) NOT NULL ,
|
||||
contents TEXT NOT NULL
|
||||
);
|
||||
|
||||
GRANT SELECT ON msgs.text_messages TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Actual messages
|
||||
--
|
||||
|
||||
CREATE TABLE msgs.messages(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
receiver_id BIGINT NOT NULL ,
|
||||
sender_id BIGINT ,
|
||||
text_content_id BIGINT ,
|
||||
event_content_id BIGINT ,
|
||||
CHECK(
|
||||
sender_id IS NULL AND text_content_id IS NULL AND event_content_id IS NOT NULL
|
||||
OR sender_id IS NOT NULL AND text_content_id IS NOT NULL AND event_content_id IS NULL )
|
||||
);
|
||||
|
||||
CREATE INDEX idx_messages_receiver
|
||||
ON msgs.messages( receiver_id );
|
||||
|
||||
CREATE UNIQUE INDEX idx_messages_e_event
|
||||
ON msgs.messages( event_content_id )
|
||||
WHERE event_content_id IS NOT NULL;
|
||||
|
||||
CREATE INDEX idx_messages_sender
|
||||
ON msgs.messages( sender_id )
|
||||
WHERE sender_id IS NOT NULL;
|
||||
|
||||
CREATE INDEX idx_messages_t_text
|
||||
ON msgs.messages( text_content_id )
|
||||
WHERE text_content_id IS NOT NULL;
|
||||
|
||||
ALTER TABLE msgs.messages
|
||||
ADD CONSTRAINT fk_messages_receiver
|
||||
FOREIGN KEY ( receiver_id ) REFERENCES msgs.receivers ,
|
||||
ADD CONSTRAINT fk_messages_sender
|
||||
FOREIGN KEY ( sender_id ) REFERENCES msgs.senders ,
|
||||
ADD CONSTRAINT fk_messages_text
|
||||
FOREIGN KEY ( text_content_id ) REFERENCES msgs.text_messages ,
|
||||
ADD CONSTRAINT fk_messages_event
|
||||
FOREIGN KEY ( event_content_id ) REFERENCES events.events
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Empire message delivery
|
||||
--
|
||||
|
||||
CREATE TABLE msgs.empire_delivery(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
empire_id INT NOT NULL ,
|
||||
message_id BIGINT NOT NULL ,
|
||||
in_inbox BOOLEAN NOT NULL ,
|
||||
status message_status NOT NULL ,
|
||||
emailed BOOLEAN NOT NULL ,
|
||||
recaped BOOLEAN NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_edelivery_empire
|
||||
ON msgs.empire_delivery ( empire_id );
|
||||
|
||||
CREATE UNIQUE INDEX idx_edelivery_message
|
||||
ON msgs.empire_delivery ( message_id , empire_id , in_inbox );
|
||||
|
||||
CREATE INDEX idx_edelivery_access
|
||||
ON msgs.empire_delivery ( empire_id , in_inbox , status );
|
||||
|
||||
CREATE INDEX idx_edelivery_status
|
||||
ON msgs.empire_delivery ( status , emailed , recaped );
|
||||
|
||||
ALTER TABLE msgs.empire_delivery
|
||||
ADD CONSTRAINT fk_edelivery_empire
|
||||
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_edelivery_message
|
||||
FOREIGN KEY ( message_id ) REFERENCES msgs.messages
|
||||
ON DELETE CASCADE;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Admin message delivery
|
||||
--
|
||||
|
||||
CREATE TABLE msgs.admin_delivery(
|
||||
id BIGSERIAL PRIMARY KEY ,
|
||||
admin_id INT NOT NULL ,
|
||||
message_id BIGINT NOT NULL ,
|
||||
in_inbox BOOLEAN NOT NULL ,
|
||||
status message_status NOT NULL ,
|
||||
emailed BOOLEAN NOT NULL
|
||||
);
|
||||
|
||||
CREATE INDEX idx_adelivery_admin
|
||||
ON msgs.admin_delivery ( admin_id );
|
||||
|
||||
CREATE INDEX idx_adelivery_message
|
||||
ON msgs.admin_delivery ( message_id );
|
||||
|
||||
CREATE INDEX idx_adelivery_status
|
||||
ON msgs.admin_delivery ( status , emailed );
|
||||
|
||||
ALTER TABLE msgs.admin_delivery
|
||||
ADD CONSTRAINT fk_adelivery_admin
|
||||
FOREIGN KEY ( admin_id ) REFERENCES admin.administrators
|
||||
ON DELETE CASCADE ,
|
||||
ADD CONSTRAINT fk_adelivery_message
|
||||
FOREIGN KEY ( message_id ) REFERENCES msgs.messages;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- E-mail notification status
|
||||
--
|
||||
|
||||
CREATE TABLE msgs.email_notifications(
|
||||
account_id INT PRIMARY KEY ,
|
||||
last_sent TIMESTAMP WITHOUT TIME ZONE
|
||||
NOT NULL DEFAULT now()
|
||||
);
|
||||
|
||||
ALTER TABLE msgs.email_notifications
|
||||
ADD CONSTRAINT fk_emailnotifications_account
|
||||
FOREIGN KEY ( account_id ) REFERENCES users.active_accounts
|
||||
ON DELETE CASCADE ON UPDATE CASCADE;
|
|
@ -0,0 +1,128 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Definitions management functions
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
--
|
||||
-- Creates or updates a language definition
|
||||
--
|
||||
-- Parameters:
|
||||
-- lid Language identifier
|
||||
-- lnm Language name
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION defs.uoc_language( lid TEXT , lnm TEXT )
|
||||
RETURNS VOID
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
BEGIN
|
||||
INSERT INTO defs.languages ( language , name )
|
||||
VALUES ( lower( lid ) , lnm );
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
UPDATE defs.languages SET name = lnm
|
||||
WHERE language = lower( lid );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION defs.uoc_language( TEXT , TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION defs.uoc_language( lid TEXT , lnm TEXT , a_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
BEGIN
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Updating language ' || lid );
|
||||
PERFORM defs.uoc_language( lid , lnm );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION defs.uoc_language( TEXT, TEXT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Creates or updates a translation
|
||||
--
|
||||
-- Parameters:
|
||||
-- lid Language identifier
|
||||
-- sid String identifier
|
||||
-- txt Translation
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION defs.uoc_translation( lid TEXT , sid TEXT , txt TEXT )
|
||||
RETURNS VOID
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
isid INT;
|
||||
ilid INT;
|
||||
BEGIN
|
||||
-- Get language
|
||||
SELECT INTO ilid id FROM defs.languages
|
||||
WHERE language = lid;
|
||||
|
||||
-- Create string, if needed
|
||||
BEGIN
|
||||
INSERT INTO defs.strings (name) VALUES ( sid )
|
||||
RETURNING id INTO isid;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
SELECT INTO isid id FROM defs.strings
|
||||
WHERE name = sid;
|
||||
END;
|
||||
|
||||
-- Create or update translation
|
||||
BEGIN
|
||||
INSERT INTO defs.translations ( string_id , lang_id , translated_string )
|
||||
VALUES ( isid , ilid , txt );
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
UPDATE defs.translations SET translated_string = txt
|
||||
WHERE string_id = isid AND lang_id = ilid;
|
||||
END;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION defs.uoc_translation( TEXT , TEXT , TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION defs.uoc_translation( lid TEXT , sid TEXT , txt TEXT , a_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
BEGIN
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Updating string ' || sid || ' in language ' || lid );
|
||||
PERFORM defs.uoc_translation( lid , sid , txt );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION defs.uoc_translation( TEXT, TEXT , TEXT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Translations view (used to load all translations)
|
||||
--
|
||||
|
||||
CREATE VIEW defs.translations_view
|
||||
AS SELECT l.language AS language_id , l.name AS language_name ,
|
||||
s.name AS string_id , t.translated_string AS translation
|
||||
FROM defs.translations t
|
||||
INNER JOIN defs.strings s
|
||||
ON s.id = t.string_id
|
||||
INNER JOIN defs.languages l
|
||||
ON l.id = t.lang_id;
|
||||
|
||||
GRANT SELECT ON defs.translations_view TO :dbuser;
|
||||
|
||||
|
|
@ -0,0 +1,158 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- System management functions
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Gets the next tick's identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.get_tick( )
|
||||
RETURNS BIGINT
|
||||
STRICT STABLE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
SELECT next_tick FROM sys.status;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Registers a new ticker task
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.register_ticker_task( t_name TEXT )
|
||||
RETURNS INT
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
INSERT INTO sys.ticker ( task_name , status )
|
||||
VALUES ( $1 , 'RUNNING' )
|
||||
RETURNING id;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.register_ticker_task( TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Indicates that a ticker task was started automatically
|
||||
--
|
||||
-- Parameters:
|
||||
-- task_id Task identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.set_task_started( task_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
t_name TEXT;
|
||||
BEGIN
|
||||
SELECT INTO t_name task_name FROM sys.ticker
|
||||
WHERE id = task_id AND status = 'AUTO' FOR UPDATE;
|
||||
IF FOUND
|
||||
THEN
|
||||
UPDATE sys.ticker SET status = 'RUNNING' , auto_start = NULL
|
||||
WHERE id = task_id;
|
||||
PERFORM sys.write_log( 'Ticker' , 'INFO'::log_level , 'Scheduled task ''' || t_name
|
||||
|| ''' has been enabled' );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.set_task_started( INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Starts or stops a task
|
||||
--
|
||||
-- Parameters:
|
||||
-- admin_id Administrator identifier
|
||||
-- task_id Task identifier
|
||||
-- running Whether the task should be started or stopped
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.set_task_running( admin_id INT , task_id INT , running BOOLEAN )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
n_stat ticker_task_status;
|
||||
t_name TEXT;
|
||||
BEGIN
|
||||
n_stat := ( CASE WHEN running THEN 'RUNNING' ELSE 'STOPPED' END );
|
||||
SELECT INTO t_name task_name FROM sys.ticker
|
||||
WHERE id = task_id AND status <> n_stat FOR UPDATE;
|
||||
IF FOUND
|
||||
THEN
|
||||
UPDATE sys.ticker SET status = n_stat , auto_start = NULL
|
||||
WHERE id = task_id;
|
||||
PERFORM admin.write_log( admin_id , 'INFO'::log_level , 'Ticker task ''' || t_name
|
||||
|| ''' changed to status ' || n_stat );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.set_task_running( INT , INT , BOOLEAN ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Schedules a task to start automatically at a later date
|
||||
--
|
||||
-- Parameters:
|
||||
-- admin_id Administrator identifier
|
||||
-- task_id Task identifier
|
||||
-- delay Delay, in seconds, before the task starts
|
||||
--
|
||||
-- Returns:
|
||||
-- start_at Time and date at which the task will start
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.schedule_task( admin_id INT , task_id INT , delay BIGINT , OUT start_at TIMESTAMP WITHOUT TIME ZONE )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
t_name TEXT;
|
||||
BEGIN
|
||||
start_at := now() + ( delay || 's' )::INTERVAL;
|
||||
|
||||
SELECT INTO t_name task_name FROM sys.ticker
|
||||
WHERE id = task_id FOR UPDATE;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
UPDATE sys.ticker SET status = 'AUTO' , auto_start = start_at WHERE id = task_id;
|
||||
PERFORM admin.write_log( admin_id , 'INFO'::log_level , 'Ticker task ''' || t_name
|
||||
|| ''' scheduled to start ' || start_at );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.schedule_task( INT , INT , BIGINT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
|
@ -0,0 +1,250 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Logging functions and triggers
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- LOG CLEANUP --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
|
||||
|
||||
--
|
||||
-- Remove expired entries from a log table
|
||||
--
|
||||
-- Parameters:
|
||||
-- l_type Log table to clean up
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.clean_log_table( l_type log_type )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
expiry INT;
|
||||
expiry_int INTERVAL;
|
||||
BEGIN
|
||||
expiry := floor( sys.get_constant( 'log.maxAge.' || lower( l_type::TEXT ) ) );
|
||||
expiry_int := ( expiry || 's' )::INTERVAL;
|
||||
EXECUTE 'DELETE FROM ' || l_type::TEXT || '.logs WHERE t <= $1'
|
||||
USING now() - expiry_int;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Clean all log tables
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.clean_logs( )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
lt log_type;
|
||||
BEGIN
|
||||
FOR lt IN SELECT x FROM unnest( enum_range( NULL::log_type ) ) AS x
|
||||
LOOP
|
||||
PERFORM sys.clean_log_table( lt );
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.clean_logs( ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- LOG APPENDERS --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
|
||||
|
||||
--
|
||||
-- Write an user log entry
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION users.write_log( account_id INT , lv log_level , msg TEXT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
BEGIN
|
||||
INSERT INTO users.logs (credentials_id , level , message)
|
||||
VALUES ( account_id , lv , msg );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Write an administrative log entry
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.write_log( adm_id INT , lv log_level , msg TEXT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
BEGIN
|
||||
INSERT INTO admin.logs ( admin_id , level , message )
|
||||
VALUES ( adm_id , lv , msg );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Write a system log entry
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.write_log( cmp TEXT , lv log_level , msg TEXT , OUT entry_id BIGINT )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
BEGIN
|
||||
INSERT INTO sys.logs( component , level , message )
|
||||
VALUES ( cmp , lv , msg )
|
||||
RETURNING id INTO entry_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.write_log( TEXT , log_level , TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Append an exception log entry
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.append_exception( l_id BIGINT , cname TEXT , msg TEXT , OUT entry_id BIGINT )
|
||||
CALLED ON NULL INPUT
|
||||
VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
d INT;
|
||||
BEGIN
|
||||
SELECT INTO d max( depth ) FROM sys.exceptions
|
||||
WHERE log_id = l_id;
|
||||
IF d IS NULL THEN
|
||||
d := 0;
|
||||
END IF;
|
||||
d := d + 1;
|
||||
|
||||
INSERT INTO sys.exceptions ( log_id , depth , exc_class , message )
|
||||
VALUES ( l_id , d , cname , msg )
|
||||
RETURNING id INTO entry_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.append_exception( BIGINT , TEXT , TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Append a stack trace entry
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.append_trace( e_id BIGINT , loc TEXT , f_name TEXT , lnb INT )
|
||||
RETURNS VOID
|
||||
CALLED ON NULL INPUT
|
||||
VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
d INT;
|
||||
BEGIN
|
||||
SELECT INTO d max( depth ) FROM sys.stack_traces
|
||||
WHERE exception_id = e_id;
|
||||
IF d IS NULL THEN
|
||||
d := 0;
|
||||
END IF;
|
||||
d := d + 1;
|
||||
|
||||
INSERT INTO sys.stack_traces ( exception_id , depth , location , file_name , line_number )
|
||||
VALUES ( e_id , d , loc , f_name , lnb );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.append_trace( BIGINT , TEXT , TEXT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- LOGS VIEW FOR EASY SELECTION --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
|
||||
|
||||
CREATE VIEW sys.system_logs_view
|
||||
AS SELECT l.id , l.t , l.component , l.level , l.message ,
|
||||
( CASE WHEN e.id IS NOT NULL THEN l.id ELSE NULL END )::BIGINT AS exception_id
|
||||
FROM sys.logs l
|
||||
LEFT OUTER JOIN sys.exceptions e ON e.log_id = l.id AND e.depth = 1;
|
||||
|
||||
GRANT SELECT ON sys.system_logs_view TO :dbuser;
|
||||
|
||||
|
||||
CREATE VIEW sys.admin_logs_view
|
||||
AS SELECT NULL::BIGINT AS id , l.t , a.appear_as AS component , l.level ,
|
||||
l.message , NULL::BIGINT AS exception_id
|
||||
FROM admin.logs l
|
||||
INNER JOIN admin.administrators a ON a.id = l.admin_id;
|
||||
|
||||
GRANT SELECT ON sys.admin_logs_view TO :dbuser;
|
||||
|
||||
|
||||
CREATE VIEW sys.player_logs_view
|
||||
AS SELECT NULL::BIGINT AS id , l.t , a.address AS component , l.level ,
|
||||
l.message , NULL::BIGINT AS exception_id
|
||||
FROM users.logs l
|
||||
INNER JOIN users.addresses a ON a.id = l.credentials_id;
|
||||
|
||||
GRANT SELECT ON sys.player_logs_view TO :dbuser;
|
||||
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- ADMIN ERROR REPORT FUNCTION --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.get_error_entries( )
|
||||
RETURNS SETOF BIGINT
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
last_report TIMESTAMP WITHOUT TIME ZONE;
|
||||
new_report TIMESTAMP WITHOUT TIME ZONE;
|
||||
e_id BIGINT;
|
||||
BEGIN
|
||||
new_report := now( );
|
||||
SELECT INTO last_report last_error_recap FROM sys.status FOR UPDATE;
|
||||
UPDATE sys.status SET last_error_recap = new_report;
|
||||
|
||||
RETURN QUERY SELECT id FROM sys.system_logs_view
|
||||
WHERE t >= last_report AND t < new_report AND exception_id IS NOT NULL
|
||||
ORDER BY t DESC;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION admin.get_error_entries( ) TO :dbuser;
|
|
@ -0,0 +1,318 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Functions that access system constants
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates or gets a constant category
|
||||
--
|
||||
-- Parameters:
|
||||
-- ccnm Constant category name
|
||||
--
|
||||
-- Returns:
|
||||
-- the category's identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.cog_constant_category( ccnm TEXT )
|
||||
RETURNS INT
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
ccid INT;
|
||||
BEGIN
|
||||
BEGIN
|
||||
INSERT INTO sys.constant_categories (name)
|
||||
VALUES (ccnm)
|
||||
RETURNING id INTO ccid;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
SELECT INTO ccid id FROM sys.constant_categories
|
||||
WHERE name = ccnm
|
||||
FOR UPDATE;
|
||||
END;
|
||||
|
||||
RETURN ccid;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates or updates a constant with no boundaries
|
||||
--
|
||||
-- Parameters:
|
||||
-- cnm Constant name
|
||||
-- cdesc Constant description
|
||||
-- ccnm Constant category name
|
||||
-- dval Default value
|
||||
--
|
||||
-- Returns:
|
||||
-- the constant's actual value
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.uoc_constant( cnm TEXT , cdesc TEXT , ccnm TEXT , dval REAL )
|
||||
RETURNS REAL
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ccid INT;
|
||||
occid INT;
|
||||
cval REAL;
|
||||
BEGIN
|
||||
ccid := sys.cog_constant_category( ccnm );
|
||||
|
||||
BEGIN
|
||||
INSERT INTO sys.constant_definitions( name , category_id , description , c_value )
|
||||
VALUES ( cnm , ccid , cdesc , dval );
|
||||
cval := dval;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
SELECT INTO occid , cval category_id , c_value FROM sys.constant_definitions
|
||||
WHERE name = cnm
|
||||
FOR UPDATE;
|
||||
|
||||
UPDATE sys.constant_definitions SET category_id = ccid , description = cdesc ,
|
||||
min_value = NULL , max_value = NULL
|
||||
WHERE name = cnm;
|
||||
|
||||
IF occid <> ccid THEN
|
||||
BEGIN
|
||||
DELETE FROM sys.constant_categories WHERE id = occid;
|
||||
EXCEPTION
|
||||
WHEN foreign_key_violation THEN
|
||||
-- Do nothing
|
||||
END; END IF;
|
||||
END;
|
||||
|
||||
RETURN cval;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.uoc_constant( TEXT , TEXT , TEXT , REAL ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates or updates a constant with a single boundary
|
||||
--
|
||||
-- Parameters:
|
||||
-- cnm Constant name
|
||||
-- cdesc Constant description
|
||||
-- ccnm Constant category name
|
||||
-- dval Default value
|
||||
-- bval Bound value
|
||||
-- ismin Whether the bound value is the minimal or maximal value for the constant
|
||||
--
|
||||
-- Returns:
|
||||
-- the constant's actual value
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.uoc_constant( cnm TEXT , cdesc TEXT , ccnm TEXT , dval REAL , bval REAL , ismin BOOLEAN )
|
||||
RETURNS REAL
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ccid INT;
|
||||
occid INT;
|
||||
cval REAL;
|
||||
mival REAL;
|
||||
maval REAL;
|
||||
BEGIN
|
||||
IF ismin THEN
|
||||
mival := bval;
|
||||
maval := NULL;
|
||||
ELSE
|
||||
maval := bval;
|
||||
mival := NULL;
|
||||
END IF;
|
||||
|
||||
ccid := sys.cog_constant_category( ccnm );
|
||||
|
||||
BEGIN
|
||||
INSERT INTO sys.constant_definitions( name , category_id , description , c_value , min_value , max_value )
|
||||
VALUES ( cnm , ccid , cdesc , dval , mival , maval );
|
||||
cval := dval;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
SELECT INTO occid , cval category_id , c_value FROM sys.constant_definitions
|
||||
WHERE name = cnm
|
||||
FOR UPDATE;
|
||||
|
||||
BEGIN
|
||||
UPDATE sys.constant_definitions SET category_id = ccid , description = cdesc ,
|
||||
min_value = mival , max_value = maval
|
||||
WHERE name = cnm;
|
||||
EXCEPTION
|
||||
WHEN check_violation THEN
|
||||
UPDATE sys.constant_definitions SET category_id = ccid , description = cdesc ,
|
||||
min_value = mival , max_value = maval , c_value = dval
|
||||
WHERE name = cnm;
|
||||
cval := dval;
|
||||
END;
|
||||
|
||||
|
||||
IF occid <> ccid THEN
|
||||
BEGIN
|
||||
DELETE FROM sys.constant_categories WHERE id = occid;
|
||||
EXCEPTION
|
||||
WHEN foreign_key_violation THEN
|
||||
-- Do nothing
|
||||
END; END IF;
|
||||
END;
|
||||
|
||||
RETURN cval;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.uoc_constant( TEXT , TEXT , TEXT , REAL , REAL , BOOLEAN ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates or updates a constant with both boundaries
|
||||
--
|
||||
-- Parameters:
|
||||
-- cnm Constant name
|
||||
-- cdesc Constant description
|
||||
-- ccnm Constant category name
|
||||
-- dval Default value
|
||||
-- mival Minimal value
|
||||
-- maval Maximal value
|
||||
--
|
||||
-- Returns:
|
||||
-- the constant's actual value
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.uoc_constant( cnm TEXT , cdesc TEXT , ccnm TEXT , dval REAL , mival REAL , maval REAL )
|
||||
RETURNS REAL
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
ccid INT;
|
||||
occid INT;
|
||||
cval REAL;
|
||||
BEGIN
|
||||
ccid := sys.cog_constant_category( ccnm );
|
||||
|
||||
BEGIN
|
||||
INSERT INTO sys.constant_definitions( name , category_id , description , c_value , min_value , max_value )
|
||||
VALUES ( cnm , ccid , cdesc , dval , mival , maval );
|
||||
cval := dval;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
SELECT INTO occid , cval category_id , c_value FROM sys.constant_definitions
|
||||
WHERE name = cnm
|
||||
FOR UPDATE;
|
||||
|
||||
BEGIN
|
||||
UPDATE sys.constant_definitions SET category_id = ccid , description = cdesc ,
|
||||
min_value = mival , max_value = maval
|
||||
WHERE name = cnm;
|
||||
EXCEPTION
|
||||
WHEN check_violation THEN
|
||||
UPDATE sys.constant_definitions SET category_id = ccid , description = cdesc ,
|
||||
min_value = mival , max_value = maval , c_value = dval
|
||||
WHERE name = cnm;
|
||||
cval := dval;
|
||||
END;
|
||||
|
||||
|
||||
IF occid <> ccid THEN
|
||||
BEGIN
|
||||
DELETE FROM sys.constant_categories WHERE id = occid;
|
||||
EXCEPTION
|
||||
WHEN foreign_key_violation THEN
|
||||
-- Do nothing
|
||||
END; END IF;
|
||||
END;
|
||||
|
||||
RETURN cval;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.uoc_constant( TEXT , TEXT , TEXT , REAL , REAL , REAL ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Updates a constant's value
|
||||
--
|
||||
-- Parameters:
|
||||
-- cnm Constant name
|
||||
-- nval New value
|
||||
-- aid Administrator attempting to update the constant
|
||||
--
|
||||
-- Returns:
|
||||
-- TRUE on success, FALSE on failure
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.set_constant( cnm TEXT , nval REAL , aid INT )
|
||||
RETURNS BOOLEAN
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
success BOOLEAN;
|
||||
BEGIN
|
||||
BEGIN
|
||||
UPDATE sys.constant_definitions SET c_value = nval
|
||||
WHERE name = cnm;
|
||||
success := FOUND;
|
||||
EXCEPTION
|
||||
WHEN check_violation THEN
|
||||
success := FALSE;
|
||||
END;
|
||||
|
||||
PERFORM admin.write_log( aid , 'INFO'::log_level , 'Constant "' || cnm || '" changed to ' || nval );
|
||||
RETURN success;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.set_constant( TEXT , REAL , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Gets a constant's value
|
||||
--
|
||||
-- Parameters:
|
||||
-- cnm Constant name
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.get_constant( cnm TEXT )
|
||||
RETURNS REAL
|
||||
STRICT STABLE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
SELECT c_value FROM sys.constant_definitions WHERE name = $1;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Constants view
|
||||
--
|
||||
|
||||
CREATE VIEW sys.constants_view
|
||||
AS SELECT cat.name AS category , cns.name AS name , cns.description AS description ,
|
||||
cns.c_value AS value , cns.min_value AS min , cns.max_value AS max
|
||||
FROM sys.constant_definitions cns
|
||||
INNER JOIN sys.constant_categories cat
|
||||
ON cat.id = cns.category_id
|
||||
ORDER BY cat.name , cns.name;
|
||||
|
||||
GRANT SELECT ON sys.constants_view TO :dbuser;
|
|
@ -0,0 +1,623 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Names management
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates or returns an empire name
|
||||
--
|
||||
-- Parameters:
|
||||
-- uid Credentials identifier
|
||||
-- nnm Empire name to create or return
|
||||
--
|
||||
-- Returns:
|
||||
-- +X the new empire name's identifier;
|
||||
-- -1 if the name is banned
|
||||
-- -2 if the name already exists and is "owned" by another player
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION naming.goc_empire_name( uid INT, nnm TEXT )
|
||||
RETURNS INT
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
nid INT;
|
||||
BEGIN
|
||||
PERFORM name FROM naming.banned_names WHERE name = lower( nnm );
|
||||
IF FOUND
|
||||
THEN
|
||||
RETURN -1;
|
||||
END IF;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO naming.empire_names ( owner_id , name )
|
||||
VALUES ( uid , nnm )
|
||||
RETURNING id INTO nid;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
SELECT INTO nid id , owner_id FROM naming.empire_names
|
||||
WHERE lower( name ) = lower( nnm ) AND owner_id = uid;
|
||||
IF NOT FOUND THEN
|
||||
RETURN -2;
|
||||
END IF;
|
||||
END;
|
||||
RETURN nid;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Generates a random name.
|
||||
--
|
||||
-- Parameters:
|
||||
-- len Length of the random name
|
||||
--
|
||||
-- Returns:
|
||||
-- the random name
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION naming.randomize( len INT )
|
||||
RETURNS TEXT
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
i INT;
|
||||
result TEXT;
|
||||
ok_chars CHAR ARRAY[16] := ARRAY['0','1','2','3','4','5','6','7','8','9','A','B','C','D','E','F'];
|
||||
BEGIN
|
||||
result := '';
|
||||
FOR i IN 1 .. len
|
||||
LOOP
|
||||
result := result || ok_chars[1 + floor( random() * 16 )::int];
|
||||
END LOOP;
|
||||
RETURN result;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Generates a new map name
|
||||
--
|
||||
-- Parameters:
|
||||
-- prefix Prefix of the map name
|
||||
--
|
||||
-- Returns:
|
||||
-- the new name's identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION naming.create_map_name( prefix TEXT )
|
||||
RETURNS INT
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
len INT;
|
||||
nid INT;
|
||||
BEGIN
|
||||
len := 20 - ( length( prefix ) + 3 );
|
||||
LOOP
|
||||
BEGIN
|
||||
INSERT INTO naming.map_names( name )
|
||||
VALUES ( prefix || '-[' || naming.randomize( len ) || ']' )
|
||||
RETURNING id INTO nid;
|
||||
RETURN nid;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Resets a map name to a random value
|
||||
--
|
||||
-- Parameters:
|
||||
-- nid Identifier of the name to reset
|
||||
-- prefix Prefix of the new name
|
||||
--
|
||||
CREATE OR REPLACE FUNCTION naming.reset_map_name( nid INT , prefix TEXT )
|
||||
RETURNS TEXT
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
len INT;
|
||||
n_name TEXT;
|
||||
BEGIN
|
||||
len := 20 - ( length( prefix ) + 3 );
|
||||
LOOP
|
||||
BEGIN
|
||||
n_name := prefix || '-[' || naming.randomize( len ) || ']';
|
||||
UPDATE naming.map_names SET name = n_name WHERE id = nid;
|
||||
RETURN n_name;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Resets an empire name
|
||||
--
|
||||
-- Parameters:
|
||||
-- nid Identifier of the name to reset
|
||||
-- prefix Prefix of the new name
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION naming.reset_empire_name( nid INT , prefix TEXT )
|
||||
RETURNS TEXT
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
len INT;
|
||||
n_name TEXT;
|
||||
BEGIN
|
||||
len := 20 - length( prefix );
|
||||
LOOP
|
||||
BEGIN
|
||||
n_name := prefix || naming.randomize( len );
|
||||
UPDATE naming.empire_names SET name = n_name WHERE id = nid;
|
||||
RETURN n_name;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Forcibly changes a map name
|
||||
--
|
||||
-- Parameters:
|
||||
-- nid Identifier of the name
|
||||
-- uid Identifier of the user who's changing the name
|
||||
-- nnm New name
|
||||
--
|
||||
-- Returns:
|
||||
-- 0 Success
|
||||
-- -1 Banned name
|
||||
-- -2 Unavailable name
|
||||
--
|
||||
CREATE OR REPLACE FUNCTION naming.change_map_name( nid INT , uid INT , nnm TEXT )
|
||||
RETURNS INT
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
BEGIN
|
||||
-- Is the name banned?
|
||||
PERFORM name FROM naming.banned_names WHERE name = lower( nnm );
|
||||
IF FOUND
|
||||
THEN
|
||||
RETURN -1;
|
||||
END IF;
|
||||
|
||||
-- Are we *actually* changing it?
|
||||
PERFORM id FROM naming.map_names
|
||||
WHERE id = nid AND name <> nnm
|
||||
FOR UPDATE;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
RETURN 0;
|
||||
END IF;
|
||||
|
||||
-- Rename it
|
||||
BEGIN
|
||||
UPDATE naming.map_names SET name = nnm
|
||||
WHERE id = nid;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
RETURN -2;
|
||||
END;
|
||||
|
||||
-- Update change record
|
||||
BEGIN
|
||||
INSERT INTO naming.changed_map_names (name_id,named_by)
|
||||
VALUES (nid , uid);
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
DELETE FROM naming.validated_map_names WHERE name_id = nid;
|
||||
UPDATE naming.changed_map_names
|
||||
SET named_at = now( ), named_by = uid
|
||||
WHERE name_id = nid;
|
||||
END;
|
||||
|
||||
RETURN 0;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Changes a map name if enough time has elapsed
|
||||
--
|
||||
-- Parameters:
|
||||
-- nid Identifier of the name
|
||||
-- uid Identifier of the user who's changing the name
|
||||
-- nnm New name
|
||||
-- mtime Minimal time between renames
|
||||
--
|
||||
-- Returns:
|
||||
-- 0 Success
|
||||
-- 1 Banned name
|
||||
-- 2 Unavailable name
|
||||
-- 3 Too early
|
||||
--
|
||||
CREATE OR REPLACE FUNCTION naming.change_map_name( nid INT , uid INT , nnm TEXT , mtime INTERVAL )
|
||||
RETURNS INT
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
lren TIMESTAMP WITHOUT TIME ZONE;
|
||||
BEGIN
|
||||
-- Is the name banned?
|
||||
PERFORM name FROM naming.banned_names WHERE name = lower( nnm );
|
||||
IF FOUND
|
||||
THEN
|
||||
RETURN 1;
|
||||
END IF;
|
||||
|
||||
-- Are we *actually* changing it?
|
||||
PERFORM id FROM naming.map_names
|
||||
WHERE id = nid AND name <> nnm
|
||||
FOR UPDATE;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
RETURN 0;
|
||||
END IF;
|
||||
|
||||
-- Check/lock change record
|
||||
SELECT INTO lren named_at FROM naming.changed_map_names
|
||||
WHERE name_id = nid FOR UPDATE;
|
||||
IF FOUND AND lren + mtime > now()
|
||||
THEN
|
||||
RETURN 3;
|
||||
END IF;
|
||||
|
||||
-- Rename it
|
||||
BEGIN
|
||||
UPDATE naming.map_names SET name = nnm
|
||||
WHERE id = nid;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
RETURN 2;
|
||||
END;
|
||||
|
||||
-- Update change record
|
||||
BEGIN
|
||||
INSERT INTO naming.changed_map_names (name_id,named_by)
|
||||
VALUES (nid , uid);
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
DELETE FROM naming.validated_map_names WHERE name_id = nid;
|
||||
UPDATE naming.changed_map_names
|
||||
SET named_at = now( ), named_by = uid
|
||||
WHERE name_id = nid;
|
||||
END;
|
||||
|
||||
RETURN 0;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Marks a map name as validated
|
||||
--
|
||||
-- Paramaters:
|
||||
-- a_id Administrator identifier
|
||||
-- n_id Name identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION naming.validate_map_name( a_id INT , n_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
nm TEXT;
|
||||
BEGIN
|
||||
SELECT INTO nm name
|
||||
FROM naming.map_names
|
||||
WHERE id = n_id;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
INSERT INTO naming.validated_map_names( name_id , validated_by )
|
||||
VALUES ( n_id , a_id );
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Map name #' || n_id || ' (' || nm || ') validated' );
|
||||
EXCEPTION
|
||||
WHEN unique_violation OR foreign_key_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION naming.validate_map_name( INT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Rejects a map name
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- n_id Name identifier
|
||||
-- ban_name Whether the old name should be banned
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION naming.reject_map_name( a_id INT , n_id INT , ban_name BOOLEAN )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
c_name TEXT;
|
||||
n_name TEXT;
|
||||
u_id INT;
|
||||
warned BOOLEAN;
|
||||
n_warnings INT;
|
||||
BEGIN
|
||||
-- Get current name and player ID
|
||||
SELECT INTO c_name , u_id n.name , cn.named_by
|
||||
FROM naming.map_names n
|
||||
INNER JOIN naming.changed_map_names cn ON cn.name_id = n.id
|
||||
WHERE n.id = n_id
|
||||
FOR UPDATE;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Forcibly rename the planet
|
||||
n_name := naming.reset_map_name( n_id , 'P' );
|
||||
|
||||
-- Update battle
|
||||
PERFORM battles.rename_planet( n_id , n_name );
|
||||
|
||||
-- Send warning
|
||||
SELECT INTO warned , n_warnings * FROM admin.give_player_warning( a_id , u_id );
|
||||
|
||||
-- Send internal message
|
||||
PERFORM events.map_name_rejected_event( u_id , n_id , c_name , n_name , warned , n_warnings );
|
||||
PERFORM msgs.deliver_internal( );
|
||||
|
||||
-- Add validation and log entry
|
||||
DELETE FROM naming.validated_map_names WHERE name_id = n_id;
|
||||
INSERT INTO naming.validated_map_names( name_id , validated_by )
|
||||
VALUES ( n_id , a_id );
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Map name #' || n_id || ' (' || c_name || ') rejected' );
|
||||
|
||||
-- Ban old name
|
||||
IF ban_name
|
||||
THEN
|
||||
BEGIN
|
||||
INSERT INTO naming.banned_names ( name , added_by )
|
||||
VALUES ( lower( c_name ) , a_id );
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Name "' || lower( c_name ) || '" banned' );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION naming.reject_map_name( INT , INT , BOOLEAN ) TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Rejects an empire's name
|
||||
--
|
||||
-- a_id Administrator identifier
|
||||
-- n_id Name identifier
|
||||
-- ban_name Whether the old name should be banned
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION naming.reject_empire_name( a_id INT , n_id INT , ban_name BOOLEAN )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
c_name TEXT;
|
||||
n_name TEXT;
|
||||
u_id INT;
|
||||
warned BOOLEAN;
|
||||
n_warnings INT;
|
||||
BEGIN
|
||||
-- Get current name and player ID
|
||||
SELECT INTO c_name , u_id n.name , n.owner_id
|
||||
FROM naming.empire_names n WHERE n.id = n_id
|
||||
FOR UPDATE;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Forcibly rename the empire
|
||||
n_name := naming.reset_empire_name( n_id , 'Rude Empire ' );
|
||||
|
||||
-- Update battles
|
||||
UPDATE battles.empires SET name = n_name WHERE empire_id = n_id;
|
||||
UPDATE msgs.senders SET name = n_name WHERE sender_type = 'EMP' AND empire_id = n_id;
|
||||
UPDATE msgs.receivers SET name = n_name WHERE receiver_type = 'EMP' AND empire_id = n_id;
|
||||
|
||||
-- Send warning
|
||||
SELECT INTO warned , n_warnings * FROM admin.give_player_warning( a_id , u_id );
|
||||
|
||||
-- Send internal message
|
||||
PERFORM events.empire_name_rejected_event( n_id , c_name , n_name , warned , n_warnings );
|
||||
PERFORM msgs.deliver_internal( );
|
||||
|
||||
-- Add log entry
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Empire name #' || n_id || ' (' || c_name || ') forcibly renamed' );
|
||||
|
||||
-- Ban name if requested
|
||||
IF ban_name
|
||||
THEN
|
||||
BEGIN
|
||||
INSERT INTO naming.banned_names ( name , added_by )
|
||||
VALUES ( lower( c_name ) , a_id );
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Name "' || lower( c_name ) || '" banned' );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION naming.reject_empire_name( INT , INT , BOOLEAN ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Forcibly disbands an alliance, sending a warning to its leader
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- al_id Alliance identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION naming.reject_alliance_name( a_id INT , al_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
e_id INT;
|
||||
u_id INT;
|
||||
c_name TEXT;
|
||||
warned BOOLEAN;
|
||||
n_warnings INT;
|
||||
BEGIN
|
||||
-- Get current name, leader ID and player ID
|
||||
SELECT INTO c_name , e_id , u_id a.tag , a.leader_id , n.owner_id
|
||||
FROM emp.alliances a
|
||||
INNER JOIN naming.empire_names n ON n.id = a.leader_id
|
||||
WHERE a.id = al_id FOR UPDATE;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Disband the alliance
|
||||
PERFORM emp.leave_alliance( e_id );
|
||||
|
||||
-- Send warning
|
||||
SELECT INTO warned , n_warnings * FROM admin.give_player_warning( a_id , u_id );
|
||||
|
||||
-- Send internal message
|
||||
PERFORM events.alliance_name_rejected_event( e_id , c_name , warned , n_warnings );
|
||||
PERFORM msgs.deliver_internal( );
|
||||
|
||||
-- Add log entry
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Alliance ' || c_name || ' disbanded' );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION naming.reject_alliance_name( INT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Allows a modified map name to be renamed earlier than it should
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- n_id Name identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION naming.allow_map_name_change( a_id INT , n_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
nm TEXT;
|
||||
mdelay BIGINT;
|
||||
BEGIN
|
||||
SELECT INTO nm n.name
|
||||
FROM naming.map_names n
|
||||
INNER JOIN naming.changed_map_names c ON c.name_id = n.id
|
||||
INNER JOIN naming.validated_map_names v ON v.name_id = n.id
|
||||
WHERE id = n_id
|
||||
FOR UPDATE;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
mdelay := 1 + floor( sys.get_constant( 'map.names.minDelay' ) * sys.get_constant( 'map.names.minDelay.units' ) )::BIGINT;
|
||||
UPDATE naming.changed_map_names
|
||||
SET named_at = now() - ( mdelay::BIGINT || 's' )::INTERVAL
|
||||
WHERE name_id = n_id;
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Allowed early modification of map name #' || n_id || ' (' || nm || ')' );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION naming.allow_map_name_change( INT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Names and status
|
||||
--
|
||||
|
||||
CREATE TYPE name_status
|
||||
AS ENUM( 'MAP_PENDING' , 'MAP_VALIDATED' , 'EMPIRE' , 'ALLIANCE' );
|
||||
|
||||
CREATE VIEW naming.names_view
|
||||
AS SELECT en.id , en.name , ( CASE WHEN e IS NULL THEN NULL ELSE '' END )::TEXT AS extra ,
|
||||
en.owner_id AS account , 'EMPIRE'::name_status AS status
|
||||
FROM naming.empire_names en
|
||||
LEFT OUTER JOIN emp.empires e ON en.id = e.name_id
|
||||
UNION ALL SELECT n.id , n.name , NULL::TEXT AS extra , c.named_by AS account ,
|
||||
( CASE
|
||||
WHEN v.name_id IS NULL THEN 'MAP_PENDING'
|
||||
ELSE 'MAP_VALIDATED'
|
||||
END )::name_status AS status
|
||||
FROM naming.map_names n
|
||||
INNER JOIN naming.changed_map_names c ON c.name_id = n.id
|
||||
LEFT OUTER JOIN naming.validated_map_names v ON v.name_id = c.name_id
|
||||
UNION ALL SELECT a.id , a.tag AS name , a.name AS extra , l.owner_id AS account ,
|
||||
'ALLIANCE'::name_status AS status
|
||||
FROM emp.alliances a
|
||||
INNER JOIN naming.empire_names l ON l.id = a.leader_id;
|
||||
|
||||
GRANT SELECT ON naming.names_view TO :dbuser;
|
||||
|
||||
|
||||
CREATE VIEW naming.names_status_view
|
||||
AS SELECT status , count(*) AS count
|
||||
FROM naming.names_view
|
||||
GROUP BY status;
|
||||
|
||||
GRANT SELECT ON naming.names_status_view TO :dbuser;
|
|
@ -0,0 +1,379 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Functions and views for technologies and buildables
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- "Basic" buildables view (buildables that do not depend on any technology)
|
||||
--
|
||||
|
||||
CREATE VIEW tech.basic_buildables
|
||||
AS SELECT b.* FROM tech.buildables b
|
||||
LEFT OUTER JOIN tech.buildable_requirements r
|
||||
ON r.buildable_id = b.name_id
|
||||
WHERE r.buildable_id IS NULL;
|
||||
|
||||
|
||||
--
|
||||
-- Buildings view
|
||||
--
|
||||
|
||||
CREATE VIEW tech.buildings_view
|
||||
AS SELECT b.name_id , b.description_id , b.cost , b.work , b.upkeep ,
|
||||
bld.workers , bld.output_type , bld.output
|
||||
FROM tech.buildables b
|
||||
INNER JOIN tech.buildings bld
|
||||
ON b.name_id = bld.buildable_id;
|
||||
|
||||
|
||||
--
|
||||
-- Ships view
|
||||
--
|
||||
|
||||
CREATE VIEW tech.ships_view
|
||||
AS SELECT b.name_id , b.description_id , b.cost , b.work , b.upkeep ,
|
||||
s.flight_time , s.power
|
||||
FROM tech.buildables b
|
||||
INNER JOIN tech.ships s
|
||||
ON b.name_id = s.buildable_id;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates or updates a technology line
|
||||
--
|
||||
-- Parameters:
|
||||
-- tln Tech line name
|
||||
-- tld Tech line description
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION tech.uoc_line( tln TEXT , tld TEXT )
|
||||
RETURNS VOID
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
nid INT;
|
||||
did INT;
|
||||
BEGIN
|
||||
-- Get string identifiers
|
||||
SELECT INTO nid id FROM defs.strings WHERE name = tln;
|
||||
SELECT INTO did id FROM defs.strings WHERE name = tld;
|
||||
|
||||
-- Try creating / updating
|
||||
BEGIN
|
||||
INSERT INTO tech.lines ( name_id , description_id )
|
||||
VALUES ( nid , did );
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
UPDATE tech.lines SET description_id = did
|
||||
WHERE name_id = nid;
|
||||
END;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION tech.uoc_line( TEXT , TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates or updates a technology level
|
||||
--
|
||||
-- Parameters:
|
||||
-- tln Tech line name
|
||||
-- lv Level
|
||||
-- lvn Level name
|
||||
-- lvd Level description
|
||||
-- lvp Points
|
||||
-- lvc Cost
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION tech.uoc_level( tln TEXT , lv INT , lvn TEXT , lvd TEXT , lvp INT , lvc INT )
|
||||
RETURNS VOID
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
lid INT;
|
||||
nid INT;
|
||||
did INT;
|
||||
BEGIN
|
||||
-- Get tech line
|
||||
SELECT INTO lid t.name_id
|
||||
FROM tech.lines t
|
||||
INNER JOIN defs.strings s
|
||||
ON s.id = t.name_id
|
||||
WHERE s.name = tln;
|
||||
|
||||
-- Get name / description IDs
|
||||
SELECT INTO nid id FROM defs.strings WHERE name = lvn;
|
||||
SELECT INTO did id FROM defs.strings WHERE name = lvd;
|
||||
|
||||
-- Create or update the level
|
||||
BEGIN
|
||||
INSERT INTO tech.levels ( line_id , level , name_id , description_id , points , cost )
|
||||
VALUES ( lid , lv , nid , did , lvp , lvc );
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
UPDATE tech.levels SET name_id = nid , description_id = did , points = lvp , cost = lvc
|
||||
WHERE line_id = lid AND level = lv;
|
||||
END;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION tech.uoc_level( TEXT , INT , TEXT , TEXT , INT , INT ) to :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates or updates a buildable definition
|
||||
--
|
||||
-- Parameters:
|
||||
-- bdn Buildable name
|
||||
-- bdd Buildable description
|
||||
-- bdc Cost
|
||||
-- bdw Work
|
||||
-- bdu Upkeep
|
||||
-- bdtn Dependency (name)
|
||||
-- bdtl Dependency (level)
|
||||
--
|
||||
-- Returns:
|
||||
-- the buildable's identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION tech.uoc_buildable( bdn TEXT , bdd TEXT , bdc INT , bdw INT , bdu INT , bdtn TEXT , bdtl INT )
|
||||
RETURNS INT
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
nid INT;
|
||||
did INT;
|
||||
tdid INT;
|
||||
BEGIN
|
||||
-- Get the various translations
|
||||
SELECT INTO nid id FROM defs.strings WHERE name = bdn;
|
||||
SELECT INTO did id FROM defs.strings WHERE name = bdd;
|
||||
IF bdtn <> '' THEN
|
||||
SELECT INTO tdid tl.id FROM tech.levels tl
|
||||
INNER JOIN defs.strings s
|
||||
ON s.id = tl.line_id
|
||||
WHERE s.name = bdtn AND tl.level = bdtl;
|
||||
END IF;
|
||||
|
||||
-- Create or update the definition
|
||||
BEGIN
|
||||
INSERT INTO tech.buildables ( name_id , description_id , cost , work , upkeep )
|
||||
VALUES ( nid , did , bdc , bdw , bdu );
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
UPDATE tech.buildables SET description_id = did , cost = bdc , work = bdw , upkeep = bdu
|
||||
WHERE name_id = nid;
|
||||
END;
|
||||
|
||||
-- Set dependencies
|
||||
DELETE FROM tech.buildable_requirements WHERE buildable_id = nid;
|
||||
IF bdtn <> '' THEN
|
||||
INSERT INTO tech.buildable_requirements ( buildable_id , level_id )
|
||||
VALUES ( nid , tdid );
|
||||
END IF;
|
||||
|
||||
RETURN nid;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Update or create a building definition (no tech dependency)
|
||||
--
|
||||
-- Parameters:
|
||||
-- bdn Buildable name
|
||||
-- bdd Buildable description
|
||||
-- bdc Cost
|
||||
-- bdw Work
|
||||
-- bdu Upkeep
|
||||
-- bdwk Workers
|
||||
-- bdot Output type
|
||||
-- bdo Output
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION tech.uoc_building( bdn TEXT , bdd TEXT , bdc INT , bdw INT ,
|
||||
bdu INT , bdwk INT , bdot building_output_type , bdo INT )
|
||||
RETURNS VOID
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
bdid INT;
|
||||
BEGIN
|
||||
bdid := tech.uoc_buildable( bdn , bdd , bdc , bdw , bdu , '' , 0 );
|
||||
|
||||
PERFORM buildable_id FROM tech.ships WHERE buildable_id = bdid;
|
||||
IF FOUND THEN
|
||||
RAISE EXCEPTION 'Trying to transform a ship into a building';
|
||||
END IF;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO tech.buildings (buildable_id, workers, output_type, output)
|
||||
VALUES (bdid , bdwk , bdot , bdo);
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
UPDATE tech.buildings SET workers = bdwk , output_type = bdot , output = bdo
|
||||
WHERE buildable_id = bdid;
|
||||
END;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION tech.uoc_building( TEXT , TEXT , INT , INT , INT , INT , building_output_type , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Update or create a building definition (with tech dependency)
|
||||
--
|
||||
-- Parameters:
|
||||
-- bdn Buildable name
|
||||
-- bdd Buildable description
|
||||
-- bdc Cost
|
||||
-- bdw Work
|
||||
-- bdu Upkeep
|
||||
-- bdwk Workers
|
||||
-- bdot Output type
|
||||
-- bdo Output
|
||||
-- bdtn Dependency (name)
|
||||
-- bdtl Dependency (level)
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION tech.uoc_building( bdn TEXT , bdd TEXT , bdc INT , bdw INT ,
|
||||
bdu INT , bdwk INT , bdot building_output_type , bdo INT ,
|
||||
bdtn TEXT , bdtl INT )
|
||||
RETURNS VOID
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
bdid INT;
|
||||
BEGIN
|
||||
bdid := tech.uoc_buildable( bdn , bdd , bdc , bdw , bdu , bdtn , bdtl );
|
||||
|
||||
PERFORM buildable_id FROM tech.ships WHERE buildable_id = bdid;
|
||||
IF FOUND THEN
|
||||
RAISE EXCEPTION 'Trying to transform a ship into a building';
|
||||
END IF;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO tech.buildings (buildable_id, workers, output_type, output)
|
||||
VALUES (bdid , bdwk , bdot , bdo);
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
UPDATE tech.buildings SET workers = bdwk , output_type = bdot , output = bdo
|
||||
WHERE buildable_id = bdid;
|
||||
END;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION tech.uoc_building( TEXT , TEXT , INT , INT , INT , INT , building_output_type , INT , TEXT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Update or create a ship definition (no tech dependency)
|
||||
--
|
||||
-- Parameters:
|
||||
-- sn Buildable name
|
||||
-- sd Buildable description
|
||||
-- sc Cost
|
||||
-- sw Work
|
||||
-- su Upkeep
|
||||
-- sp Power
|
||||
-- sft Orbital flight time
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION tech.uoc_ship( sn TEXT , sd TEXT , sc INT , sw INT ,
|
||||
su INT , sp INT , sft INT )
|
||||
RETURNS VOID
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
bdid INT;
|
||||
BEGIN
|
||||
bdid := tech.uoc_buildable( sn , sd , sc , sw , su , '' , 0 );
|
||||
|
||||
PERFORM buildable_id FROM tech.buildings WHERE buildable_id = bdid;
|
||||
IF FOUND THEN
|
||||
RAISE EXCEPTION 'Trying to transform a building into a ship';
|
||||
END IF;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO tech.ships (buildable_id, flight_time, power)
|
||||
VALUES (bdid , sft , sp);
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
UPDATE tech.ships SET flight_time = sft , power = sp
|
||||
WHERE buildable_id = bdid;
|
||||
END;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION tech.uoc_ship( TEXT , TEXT , INT , INT , INT , INT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Update or create a ship definition
|
||||
--
|
||||
-- Parameters:
|
||||
-- sn Buildable name
|
||||
-- sd Buildable description
|
||||
-- sc Cost
|
||||
-- sw Work
|
||||
-- su Upkeep
|
||||
-- sp Power
|
||||
-- sft Orbital flight time
|
||||
-- stdn Tech line name
|
||||
-- stdl Tech level
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION tech.uoc_ship( sn TEXT , sd TEXT , sc INT , sw INT ,
|
||||
su INT , sp INT , sft INT , stdn TEXT , stdl INT )
|
||||
RETURNS VOID
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
bdid INT;
|
||||
BEGIN
|
||||
bdid := tech.uoc_buildable( sn , sd , sc , sw , su , stdn , stdl );
|
||||
|
||||
PERFORM buildable_id FROM tech.buildings WHERE buildable_id = bdid;
|
||||
IF FOUND THEN
|
||||
RAISE EXCEPTION 'Trying to transform a building into a ship';
|
||||
END IF;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO tech.ships (buildable_id, flight_time, power)
|
||||
VALUES (bdid , sft , sp);
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
UPDATE tech.ships SET flight_time = sft , power = sp
|
||||
WHERE buildable_id = bdid;
|
||||
END;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION tech.uoc_ship( TEXT , TEXT , INT , INT , INT , INT , INT , TEXT , INT ) TO :dbuser;
|
||||
|
||||
|
|
@ -0,0 +1,85 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- General account view
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
--
|
||||
-- General account view
|
||||
--
|
||||
-- Allows most account-related data to be loooked up, and computes account statuses.
|
||||
--
|
||||
|
||||
CREATE VIEW users.accounts_view
|
||||
AS SELECT addr.id AS id , addr.address AS address , lang.language AS language ,
|
||||
cred.pass_md5 AS pass_md5 , cred.pass_sha1 AS pass_sha1 , cred.credits AS game_credits ,
|
||||
( CASE ( ban.account_id IS NULL )
|
||||
WHEN TRUE THEN
|
||||
( CASE ( iacc.credentials_id IS NULL )
|
||||
WHEN TRUE THEN
|
||||
( CASE ( aacc.credentials_id IS NULL )
|
||||
WHEN TRUE THEN
|
||||
'UNCONFIRMED'
|
||||
ELSE
|
||||
( CASE ( vac.status IS NULL )
|
||||
WHEN TRUE THEN
|
||||
'ACTIVE'
|
||||
ELSE
|
||||
( CASE vac.status
|
||||
WHEN 'PROCESSED' THEN
|
||||
'VACATION'
|
||||
ELSE
|
||||
'START_VACATION'
|
||||
END )
|
||||
END )
|
||||
END )
|
||||
ELSE
|
||||
( CASE ( aacc.credentials_id IS NULL )
|
||||
WHEN TRUE THEN
|
||||
( CASE ( vkey.credentials_id IS NULL )
|
||||
WHEN TRUE THEN
|
||||
'DISABLED'
|
||||
ELSE
|
||||
'REACTIVATING'
|
||||
END )
|
||||
ELSE
|
||||
'QUITTING'
|
||||
END )
|
||||
END )
|
||||
ELSE
|
||||
'BANNED'
|
||||
END ) AS status ,
|
||||
vkey.token AS validation_token , prr.token AS pwd_recovery_token ,
|
||||
acr.token AS address_change_token , naddr.address AS new_address ,
|
||||
aacc.vacation_credits AS vacation_credits ,
|
||||
floor( aacc.vacation_credits / sys.get_constant( 'vacation.cost' ) ) AS vacation_time,
|
||||
vac.since AS vacation_start ,
|
||||
iacc.since AS inactivity_begin , ires.reason AS inactivity_reason ,
|
||||
ban.ban_id AS ban_request_id
|
||||
FROM users.addresses addr
|
||||
INNER JOIN users.credentials cred
|
||||
ON cred.address_id = addr.id
|
||||
INNER JOIN defs.languages lang
|
||||
ON lang.id = cred.language_id
|
||||
LEFT OUTER JOIN users.validation_keys vkey
|
||||
ON vkey.credentials_id = cred.address_id
|
||||
LEFT OUTER JOIN users.pwd_recovery_requests prr
|
||||
ON prr.credentials_id = cred.address_id AND NOT prr.used
|
||||
LEFT OUTER JOIN users.address_change_requests acr
|
||||
ON acr.credentials_id = cred.address_id AND NOT acr.used
|
||||
LEFT OUTER JOIN users.addresses naddr
|
||||
ON naddr.id = acr.address_id
|
||||
LEFT OUTER JOIN users.active_accounts aacc
|
||||
ON aacc.credentials_id = cred.address_id
|
||||
LEFT OUTER JOIN users.vacations AS vac
|
||||
ON vac.account_id = aacc.credentials_id
|
||||
LEFT OUTER JOIN users.inactive_accounts AS iacc
|
||||
ON iacc.credentials_id = cred.address_id
|
||||
LEFT OUTER JOIN users.reasons AS ires
|
||||
ON ires.account_id = iacc.credentials_id
|
||||
LEFT OUTER JOIN users.bans AS ban
|
||||
ON ban.account_id = iacc.credentials_id;
|
||||
|
||||
GRANT SELECT ON users.accounts_view TO :dbuser;
|
|
@ -0,0 +1,662 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Empire management functions and views
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Empire creation
|
||||
--
|
||||
-- Parameters:
|
||||
-- nid Empire name identifier
|
||||
-- pid Planet identifier
|
||||
-- icash Initial cash
|
||||
--
|
||||
CREATE OR REPLACE FUNCTION emp.create_empire( nid INT , pid INT , icash REAL )
|
||||
RETURNS VOID
|
||||
STRICT
|
||||
VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
uid BIGINT;
|
||||
utp update_type;
|
||||
BEGIN
|
||||
-- Add empire and give initial planet
|
||||
INSERT INTO emp.empires ( name_id , cash )
|
||||
VALUES ( nid , icash );
|
||||
INSERT INTO emp.planets ( planet_id , empire_id )
|
||||
VALUES ( pid , nid );
|
||||
|
||||
-- Add empire update records
|
||||
FOR utp IN SELECT x FROM unnest( enum_range( NULL::update_type ) ) AS x
|
||||
WHERE x::text LIKE 'EMPIRE_%'
|
||||
LOOP
|
||||
INSERT INTO sys.updates( gu_type )
|
||||
VALUES ( utp )
|
||||
RETURNING id INTO uid;
|
||||
INSERT INTO emp.updates ( update_id , empire_id )
|
||||
VALUES ( uid , nid );
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
--
|
||||
-- Returns a planet owner's empire size
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.get_size( pid INT )
|
||||
RETURNS INT
|
||||
STRICT STABLE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
SELECT count( aep.* )::INT
|
||||
FROM emp.planets ep
|
||||
INNER JOIN emp.planets aep
|
||||
ON ep.empire_id = aep.empire_id
|
||||
WHERE ep.planet_id = $1;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Returns the empire associated with an account
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.get_current( a_id INT , OUT empire_id INT )
|
||||
STRICT STABLE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
SELECT e.name_id AS empire_id
|
||||
FROM users.credentials c
|
||||
INNER JOIN naming.empire_names en ON en.owner_id = c.address_id
|
||||
INNER JOIN emp.empires e ON e.name_id = en.id
|
||||
WHERE c.address_id = $1;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION emp.get_current( INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Implements a technology
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.implement_tech( e_id INT , l_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
e_cash REAL;
|
||||
lev INT;
|
||||
cost REAL;
|
||||
BEGIN
|
||||
SELECT INTO e_cash , lev , cost e.cash , et.level , tl.cost
|
||||
FROM emp.empires e
|
||||
INNER JOIN emp.technologies et
|
||||
ON et.line_id = l_id AND et.empire_id = e.name_id
|
||||
INNER JOIN tech.levels tl
|
||||
ON tl.line_id = l_id AND tl.level = et.level
|
||||
AND tl.points = floor( et.accumulated )
|
||||
AND tl.cost <= e.cash
|
||||
WHERE e.name_id = e_id
|
||||
FOR UPDATE OF e , et;
|
||||
|
||||
IF NOT FOUND THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
UPDATE emp.empires
|
||||
SET cash = e_cash - cost
|
||||
WHERE name_id = e_id;
|
||||
UPDATE emp.technologies
|
||||
SET level = lev + 1 , accumulated = 0
|
||||
WHERE empire_id = e_id AND line_id = l_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION emp.implement_tech( INT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Add an enemy empire
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
-- e_name New enemy name
|
||||
--
|
||||
-- Returns:
|
||||
-- err_code Error code:
|
||||
-- 0 on success
|
||||
-- 1 if the specified empire does not exist
|
||||
-- 2 if the player is being schizophrenic
|
||||
-- 3 if the enemy list already contains the specified empire
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.add_enemy_empire( e_id INT , e_name TEXT , OUT err_code INT )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
en_id INT;
|
||||
BEGIN
|
||||
SELECT INTO en_id e.name_id
|
||||
FROM emp.empires e
|
||||
INNER JOIN naming.empire_names en ON e.name_id = en.id
|
||||
WHERE lower( en.name ) = lower( e_name );
|
||||
IF NOT FOUND THEN
|
||||
err_code := 1;
|
||||
ELSEIF en_id = e_id THEN
|
||||
err_code := 2;
|
||||
ELSE
|
||||
BEGIN
|
||||
INSERT INTO emp.enemy_empires (empire_id , enemy_id)
|
||||
VALUES (e_id , en_id);
|
||||
err_code := 0;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
err_code := 3;
|
||||
END;
|
||||
END IF;
|
||||
|
||||
IF err_code = 0 THEN
|
||||
PERFORM emp.switch_enemies( e_id );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION emp.add_enemy_empire( INT , TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Add an enemy alliance
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
-- e_name Alliance tag
|
||||
--
|
||||
-- Returns:
|
||||
-- err_code Error code:
|
||||
-- 0 on success
|
||||
-- 1 if the specified alliance does not exist
|
||||
-- 2 if the player is adding his/her own alliance
|
||||
-- 3 if the enemy list already contains the specified alliance
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.add_enemy_alliance( e_id INT , e_name TEXT , OUT err_code INT )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
en_id INT;
|
||||
e_ca_id INT;
|
||||
BEGIN
|
||||
SELECT INTO en_id a.id
|
||||
FROM emp.alliances a
|
||||
WHERE lower( a.tag ) = lower( e_name );
|
||||
IF NOT FOUND THEN
|
||||
err_code := 1;
|
||||
ELSE
|
||||
SELECT INTO e_ca_id ea.alliance_id
|
||||
FROM emp.alliance_members ea
|
||||
WHERE ea.empire_id = e_id;
|
||||
IF FOUND AND en_id = e_ca_id THEN
|
||||
err_code := 2;
|
||||
ELSE
|
||||
BEGIN
|
||||
INSERT INTO emp.enemy_alliances (empire_id , alliance_id)
|
||||
VALUES (e_id , en_id);
|
||||
err_code := 0;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
err_code := 3;
|
||||
END;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
IF err_code = 0 THEN
|
||||
PERFORM emp.switch_enemies( e_id );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION emp.add_enemy_alliance( INT , TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Remove enemy empires
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
-- rem_ids Identifiers of enemy empires to remove
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.remove_enemy_empires( e_id INT , rem_ids INT[])
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
BEGIN
|
||||
DELETE FROM emp.enemy_empires
|
||||
WHERE empire_id = e_id AND enemy_id IN ( SELECT unnest( rem_ids ) AS id );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION emp.remove_enemy_empires( INT , INT[] ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Remove enemy alliances
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
-- rem_ids Identifiers of enemy alliances to remove
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.remove_enemy_alliances( e_id INT , rem_ids INT[])
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
BEGIN
|
||||
DELETE FROM emp.enemy_alliances
|
||||
WHERE empire_id = e_id AND alliance_id IN ( SELECT unnest( rem_ids ) AS id );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION emp.remove_enemy_alliances( INT , INT[] ) TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Switch enemies to attack
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.switch_enemies( e_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
BEGIN
|
||||
CREATE TEMPORARY TABLE fleet_switches(
|
||||
loc_id INT ,
|
||||
loc_name VARCHAR(20) ,
|
||||
own_id INT ,
|
||||
own_name VARCHAR(20) ,
|
||||
name VARCHAR(64) ,
|
||||
power BIGINT ,
|
||||
mode BOOLEAN
|
||||
) ON COMMIT DROP;
|
||||
INSERT INTO fleet_switches
|
||||
SELECT f.location_id , ln.name , f.owner_id , fon.name ,
|
||||
f.name , fs.power , TRUE
|
||||
FROM fleets.fleets f
|
||||
INNER JOIN emp.planets ep ON f.location_id = ep.planet_id
|
||||
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
|
||||
INNER JOIN emp.enemies el ON el.enemy = f.owner_id
|
||||
INNER JOIN fleets.stats_view fs ON fs.id = f.id
|
||||
INNER JOIN naming.map_names ln ON ln.id = f.location_id
|
||||
INNER JOIN naming.empire_names fon ON fon.id = f.owner_id
|
||||
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
|
||||
WHERE ep.empire_id = e_id AND el.empire = e_id AND m.fleet_id IS NULL
|
||||
AND NOT f.attacking;
|
||||
PERFORM events.commit_fleet_switches( TRUE );
|
||||
|
||||
FOR rec IN SELECT DISTINCT f.location_id AS location , f.owner_id AS owner , b.id AS battle
|
||||
FROM fleets.fleets f
|
||||
INNER JOIN emp.planets ep ON f.location_id = ep.planet_id
|
||||
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
|
||||
INNER JOIN emp.enemies el ON el.enemy = f.owner_id
|
||||
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
|
||||
LEFT OUTER JOIN battles.battles b
|
||||
ON b.location_id = ep.planet_id AND b.last_tick IS NULL
|
||||
WHERE ep.empire_id = e_id AND el.empire = e_id AND m.fleet_id IS NULL
|
||||
AND NOT f.attacking
|
||||
LOOP
|
||||
-- Set fleets mode
|
||||
UPDATE fleets.fleets f
|
||||
SET attacking = TRUE ,
|
||||
status = 'REDEPLOYING' ,
|
||||
penalty = ( CASE
|
||||
WHEN f2.penalty > ( 1 + fs.flight_time * 40 )
|
||||
THEN f2.penalty
|
||||
ELSE ( 1 + fs.flight_time * 40 )
|
||||
END )
|
||||
FROM fleets.fleets f2
|
||||
INNER JOIN fleets.stats_view fs ON fs.id = f2.id
|
||||
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f2.id
|
||||
WHERE f2.owner_id = rec.owner AND f2.location_id = rec.location
|
||||
AND m.fleet_id IS NULL AND f2.id = f.id;
|
||||
|
||||
-- Update battle
|
||||
PERFORM battles.set_mode( rec.battle , rec.owner , TRUE );
|
||||
END LOOP;
|
||||
|
||||
PERFORM msgs.deliver_internal( );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Deletes an empire
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.delete_empire( e_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
p_id INT;
|
||||
f_id BIGINT;
|
||||
fleets BIGINT[];
|
||||
BEGIN
|
||||
-- Lock empire
|
||||
PERFORM * FROM emp.empires WHERE name_id = e_id FOR UPDATE;
|
||||
|
||||
-- Disband fleets
|
||||
fleets := '{}'::BIGINT[];
|
||||
FOR f_id IN SELECT id FROM fleets.fleets WHERE owner_id = e_id FOR UPDATE
|
||||
LOOP
|
||||
fleets := array_append( fleets , f_id );
|
||||
END LOOP;
|
||||
PERFORM fleets.disband( e_id , fleets );
|
||||
|
||||
-- Abandon planets
|
||||
FOR p_id IN SELECT planet_id FROM emp.planets WHERE empire_id = e_id
|
||||
LOOP
|
||||
PERFORM emp.leave_planet( p_id );
|
||||
END LOOP;
|
||||
|
||||
-- Leave alliance
|
||||
PERFORM emp.leave_alliance( e_id );
|
||||
|
||||
-- Delete empire
|
||||
DELETE FROM emp.empires WHERE name_id = e_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Obtains a new planet
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
-- p_name Planet name
|
||||
--
|
||||
-- Returns:
|
||||
-- err_code Error code:
|
||||
-- 0 success
|
||||
-- 1 banned name
|
||||
-- 2 name unavailable
|
||||
-- 3 empire has planets
|
||||
--
|
||||
CREATE OR REPLACE FUNCTION emp.get_new_planet( e_id INT , p_name TEXT , OUT err_code INT )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
plid INT;
|
||||
accid INT;
|
||||
ccash REAL;
|
||||
f_id BIGINT;
|
||||
fleets BIGINT[];
|
||||
BEGIN
|
||||
-- Lock empire and check for existing planets
|
||||
SELECT INTO ccash cash FROM emp.empires WHERE name_id = e_id FOR UPDATE;
|
||||
PERFORM * FROM emp.planets WHERE empire_id = e_id LIMIT 1;
|
||||
IF FOUND
|
||||
THEN
|
||||
err_code := 3;
|
||||
RETURN;
|
||||
END IF;
|
||||
SELECT INTO accid owner_id FROM naming.empire_names WHERE id = e_id;
|
||||
|
||||
-- Get random planet and rename it
|
||||
plid := verse.get_random_planet( );
|
||||
IF plid IS NULL THEN
|
||||
err_code := 2;
|
||||
ELSE
|
||||
err_code := - naming.change_map_name( plid , accid , p_name );
|
||||
END IF;
|
||||
IF err_code <> 0
|
||||
THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
INSERT INTO emp.planets ( planet_id , empire_id )
|
||||
VALUES ( plid , e_id );
|
||||
|
||||
-- Disband fleets
|
||||
fleets := '{}'::BIGINT[];
|
||||
FOR f_id IN SELECT id FROM fleets.fleets WHERE owner_id = e_id FOR UPDATE
|
||||
LOOP
|
||||
fleets := array_append( fleets , f_id );
|
||||
END LOOP;
|
||||
PERFORM fleets.disband( e_id , fleets );
|
||||
|
||||
-- Reset to initial cash if below
|
||||
IF ccash < sys.get_constant( 'game.initialCash' )
|
||||
THEN
|
||||
UPDATE emp.empires
|
||||
SET cash = sys.get_constant( 'game.initialCash' )
|
||||
WHERE name_id = e_id;
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION emp.get_new_planet( INT , TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Enemies view
|
||||
--
|
||||
|
||||
CREATE VIEW emp.enemies
|
||||
AS SELECT iq.empire AS empire , iq.enemy AS enemy FROM
|
||||
( SELECT ee.empire_id AS empire , ee.enemy_id AS enemy
|
||||
FROM emp.enemy_empires ee
|
||||
UNION SELECT ea.empire_id AS empire , am.empire_id AS enemy
|
||||
FROM emp.enemy_alliances ea
|
||||
INNER JOIN emp.alliance_members am
|
||||
ON am.alliance_id = ea.alliance_id AND NOT am.is_pending ) AS iq
|
||||
ORDER BY iq.empire , iq.enemy;
|
||||
|
||||
|
||||
--
|
||||
-- General information view
|
||||
--
|
||||
|
||||
CREATE VIEW emp.general_information
|
||||
AS SELECT e.name_id AS id , en.name AS name ,
|
||||
( CASE
|
||||
WHEN av.status = 'QUITTING' THEN 'q'
|
||||
WHEN av.status = 'VACATION' THEN 'v'
|
||||
WHEN av.status = 'START_VACATION' THEN 's'
|
||||
ELSE NULL
|
||||
END ) AS status ,
|
||||
e.cash AS cash , a.tag AS alliance ,
|
||||
st.next_tick AS game_time ,
|
||||
av.id AS account_id
|
||||
FROM emp.empires e
|
||||
INNER JOIN naming.empire_names en ON en.id = e.name_id
|
||||
INNER JOIN users.accounts_view av ON av.id = en.owner_id
|
||||
LEFT OUTER JOIN emp.alliance_members am
|
||||
ON am.empire_id = e.name_id AND NOT am.is_pending
|
||||
LEFT OUTER JOIN emp.alliances a ON a.id = am.alliance_id
|
||||
CROSS JOIN sys.status st;
|
||||
|
||||
GRANT SELECT ON emp.general_information TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Empire planets view
|
||||
--
|
||||
|
||||
CREATE VIEW emp.planets_view
|
||||
AS SELECT e.empire_id AS empire , n.id AS id , n.name AS name
|
||||
FROM emp.planets e
|
||||
INNER JOIN verse.planets p ON p.name_id = e.planet_id
|
||||
INNER JOIN verse.systems s ON s.id = p.system_id
|
||||
INNER JOIN naming.map_names n ON n.id = e.planet_id
|
||||
ORDER BY e.empire_id , s.x , s.y , p.orbit;
|
||||
|
||||
GRANT SELECT ON emp.planets_view TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Empire overviews
|
||||
--
|
||||
|
||||
CREATE VIEW emp.planets_overview
|
||||
AS SELECT e.name_id AS empire , count( p.* ) AS planets ,
|
||||
sum( floor( p.population) ) AS population ,
|
||||
floor( avg( 100.0 * ph.current / p.population ) ) AS avg_happiness ,
|
||||
floor( sum( pm.income ) ) AS planet_income ,
|
||||
floor( sum( pm.upkeep ) ) AS planet_upkeep
|
||||
FROM emp.empires e
|
||||
LEFT OUTER JOIN emp.planets ep ON ep.empire_id = e.name_id
|
||||
LEFT OUTER JOIN verse.planets p ON p.name_id = ep.planet_id
|
||||
LEFT OUTER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
|
||||
LEFT OUTER JOIN verse.planet_money pm ON pm.planet_id = p.name_id
|
||||
GROUP BY e.name_id;
|
||||
|
||||
CREATE VIEW emp.civ_invest_acc_totals
|
||||
AS SELECT e.name_id AS empire , sum( cq.money ) AS acc_total
|
||||
FROM emp.empires e
|
||||
LEFT OUTER JOIN emp.planets ep ON ep.empire_id = e.name_id
|
||||
LEFT OUTER JOIN verse.bld_queues cq ON cq.planet_id = ep.planet_id
|
||||
GROUP BY e.name_id;
|
||||
|
||||
CREATE VIEW emp.civ_investment_view
|
||||
AS SELECT e.name_id AS empire ,
|
||||
( sum( bqi.amount * bqid.cost ) - ( CASE WHEN ciat.acc_total IS NULL THEN 0 ELSE ciat.acc_total END ) )::BIGINT AS civ_investment
|
||||
FROM emp.empires e
|
||||
LEFT OUTER JOIN emp.planets ep ON ep.empire_id = e.name_id
|
||||
LEFT OUTER JOIN emp.civ_invest_acc_totals ciat ON ciat.empire = e.name_id
|
||||
LEFT OUTER JOIN verse.bld_items bqi ON bqi.queue_id = ep.planet_id AND NOT bqi.destroy
|
||||
LEFT OUTER JOIN tech.buildables bqid ON bqid.name_id = bqi.building_id
|
||||
GROUP BY e.name_id, ciat.acc_total;
|
||||
|
||||
CREATE VIEW emp.mil_invest_acc_totals
|
||||
AS SELECT e.name_id AS empire , sum( mq.money ) AS acc_total
|
||||
FROM emp.empires e
|
||||
LEFT OUTER JOIN emp.planets ep ON ep.empire_id = e.name_id
|
||||
LEFT OUTER JOIN verse.mil_queues mq ON mq.planet_id = ep.planet_id
|
||||
GROUP BY e.name_id;
|
||||
|
||||
CREATE VIEW emp.mil_investment_view
|
||||
AS SELECT e.name_id AS empire ,
|
||||
( sum( mqi.amount * mqid.cost ) - ( CASE WHEN miat.acc_total IS NULL THEN 0 ELSE miat.acc_total END ) )::BIGINT AS mil_investment
|
||||
FROM emp.empires e
|
||||
LEFT OUTER JOIN emp.planets ep ON ep.empire_id = e.name_id
|
||||
LEFT OUTER JOIN emp.mil_invest_acc_totals miat ON miat.empire = e.name_id
|
||||
LEFT OUTER JOIN verse.mil_items mqi ON mqi.queue_id = ep.planet_id
|
||||
LEFT OUTER JOIN tech.buildables mqid ON mqid.name_id = mqi.ship_id
|
||||
GROUP BY e.name_id, miat.acc_total;
|
||||
|
||||
CREATE VIEW emp.fleets_overview
|
||||
AS SELECT e.name_id AS empire ,
|
||||
sum( sd.power * s.amount ) AS fleet_power ,
|
||||
sum( sbd.upkeep * s.amount ) AS fleet_upkeep
|
||||
FROM emp.empires e
|
||||
LEFT OUTER JOIN fleets.fleets f ON f.owner_id = e.name_id
|
||||
LEFT OUTER JOIN fleets.ships s ON s.fleet_id = f.id
|
||||
LEFT OUTER JOIN tech.ships sd ON sd.buildable_id = s.ship_id
|
||||
LEFT OUTER JOIN tech.buildables sbd ON sbd.name_id = sd.buildable_id
|
||||
GROUP BY e.name_id;
|
||||
|
||||
CREATE VIEW emp.new_messages
|
||||
AS SELECT e.name_id AS empire , count( m.* ) AS new_messages
|
||||
FROM emp.empires e
|
||||
LEFT OUTER JOIN msgs.empire_delivery m
|
||||
ON m.empire_id = e.name_id AND m.in_inbox AND m.status = 'UNREAD'
|
||||
GROUP BY e.name_id;
|
||||
|
||||
|
||||
CREATE VIEW emp.overview
|
||||
AS SELECT * FROM emp.planets_overview
|
||||
INNER JOIN emp.fleets_overview USING (empire)
|
||||
INNER JOIN emp.civ_investment_view USING (empire)
|
||||
INNER JOIN emp.mil_investment_view USING (empire)
|
||||
INNER JOIN emp.new_messages USING (empire);
|
||||
|
||||
GRANT SELECT ON emp.overview TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Empire tech lines
|
||||
--
|
||||
|
||||
CREATE VIEW emp.tech_lines_view
|
||||
AS SELECT e.name_id AS empire , tl.name_id AS tech_line ,
|
||||
t1.translated_string AS name ,
|
||||
t2.translated_string AS description
|
||||
FROM emp.empires e
|
||||
INNER JOIN emp.technologies et ON et.empire_id = e.name_id
|
||||
INNER JOIN tech.lines tl ON tl.name_id = et.line_id
|
||||
INNER JOIN naming.empire_names en ON en.id = e.name_id
|
||||
INNER JOIN users.credentials c ON c.address_id = en.owner_id
|
||||
INNER JOIN defs.translations t1 ON t1.string_id = tl.name_id AND t1.lang_id = c.language_id
|
||||
INNER JOIN defs.translations t2 ON t2.string_id = tl.description_id AND t2.lang_id = c.language_id
|
||||
ORDER BY t1.translated_string;
|
||||
|
||||
GRANT SELECT ON emp.tech_lines_view TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Empire technologies
|
||||
--
|
||||
|
||||
CREATE VIEW emp.technologies_view
|
||||
AS SELECT e.name_id AS empire , tl.name_id AS tech_line ,
|
||||
t1.translated_string AS name ,
|
||||
t2.translated_string AS description ,
|
||||
( et.level > tlv.level ) AS implemented ,
|
||||
floor( 100 * et.accumulated / tlv.points ) AS progress ,
|
||||
tlv.cost AS cost
|
||||
FROM emp.empires e
|
||||
INNER JOIN emp.technologies et ON et.empire_id = e.name_id
|
||||
INNER JOIN tech.lines tl ON tl.name_id = et.line_id
|
||||
INNER JOIN tech.levels tlv ON tlv.line_id = tl.name_id AND tlv.level <= et.level
|
||||
INNER JOIN naming.empire_names en ON en.id = e.name_id
|
||||
INNER JOIN users.credentials c ON c.address_id = en.owner_id
|
||||
INNER JOIN defs.translations t1 ON t1.string_id = tlv.name_id AND t1.lang_id = c.language_id
|
||||
INNER JOIN defs.translations t2 ON t2.string_id = tlv.description_id AND t2.lang_id = c.language_id
|
||||
ORDER BY tl.name_id , tlv.level;
|
||||
|
||||
GRANT SELECT ON emp.technologies_view TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Enemy lists
|
||||
--
|
||||
|
||||
CREATE VIEW emp.enemy_lists
|
||||
AS SELECT x.empire AS empire , x.id AS id , x.name AS name , x.alliance AS alliance
|
||||
FROM (
|
||||
SELECT el.empire_id AS empire , el.enemy_id AS id , n.name AS name , FALSE AS alliance
|
||||
FROM emp.enemy_empires el
|
||||
INNER JOIN naming.empire_names n ON n.id = el.enemy_id
|
||||
UNION SELECT el.empire_id AS empire , el.alliance_id AS id , a.tag AS name , TRUE AS alliance
|
||||
FROM emp.enemy_alliances el
|
||||
INNER JOIN emp.alliances a ON a.id = el.alliance_id
|
||||
) AS x;
|
||||
|
||||
GRANT SELECT ON emp.enemy_lists TO :dbuser;
|
|
@ -0,0 +1,232 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Various functions for in-game computations
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- sigma( x ) = exp( x ) / ( 1 + exp( x ) )
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.sigma( x REAL )
|
||||
RETURNS REAL
|
||||
STRICT IMMUTABLE SECURITY INVOKER
|
||||
AS $$
|
||||
SELECT ( CASE
|
||||
WHEN $1 < -100 THEN 0
|
||||
WHEN $1 > 100 THEN 1
|
||||
ELSE ( exp( $1 ) / ( 1 + exp( $1 ) ) )::REAL
|
||||
END );
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- poly( x , a , b , c ) = ( a * x + b ) * x + c
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.poly( x REAL , a REAL , b REAL , c REAL )
|
||||
RETURNS REAL
|
||||
STRICT IMMUTABLE SECURITY INVOKER
|
||||
AS $$
|
||||
SELECT ( $2 * $1 + $3 ) * $1 + $4;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Happiness curve, K1 constant
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.hcc_const_k1( xmax REAL , ymax REAL , xlimit REAL , ylimit REAL )
|
||||
RETURNS REAL
|
||||
STRICT IMMUTABLE SECURITY INVOKER
|
||||
AS $$
|
||||
SELECT ( ( $4 - $2 ) / ( ( $3 - $1 ) ^ 2 ) )::REAL;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Happiness curve, K2 constant
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.hcc_const_k2( ylimit REAL , yasymptote REAL )
|
||||
RETURNS REAL
|
||||
STRICT IMMUTABLE SECURITY INVOKER
|
||||
AS $$
|
||||
SELECT ( 2 * ( $1 - $2 ) )::REAL;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Happiness curve, K3 constant
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.hcc_const_k3( xmax REAL , ymax REAL , xlimit REAL , ylimit REAL , yasymptote REAL )
|
||||
RETURNS REAL
|
||||
STRICT IMMUTABLE SECURITY INVOKER
|
||||
AS $$
|
||||
SELECT ( verse.hcc_const_k1( $1 , $2 , $3 , $4 ) * 4 * ( $3 - $1 ) / ( $5 - $4 ) ) ::REAL;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Happiness curve, first part
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.hcc_part_1( x REAL , ymin REAL , ymax REAL , xmax REAL )
|
||||
RETURNS REAL
|
||||
STRICT IMMUTABLE SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
v REAL;
|
||||
BEGIN
|
||||
v := ( ymin - ymax ) / xmax;
|
||||
RETURN verse.poly( x , ( v / xmax )::REAL , ( -2 * v )::REAL , ymin );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Happiness curve, second part
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.hcc_part_2( x REAL , xmax REAL , ymax REAL , xlimit REAL , ylimit REAL )
|
||||
RETURNS REAL
|
||||
STRICT IMMUTABLE SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
k1 REAL;
|
||||
BEGIN
|
||||
k1 := verse.hcc_const_k1( xmax , ymax , xlimit , ylimit );
|
||||
RETURN verse.poly( x , k1 , ( -2 * xmax * k1 )::REAL , ( ymax + k1 * xmax * xmax )::REAL );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Happiness curve, third part
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.hcc_part_3( x REAL , xmax REAL , ymax REAL , xlimit REAL , ylimit REAL , yasymptote REAL )
|
||||
RETURNS REAL
|
||||
STRICT IMMUTABLE SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
k2 REAL;
|
||||
k3 REAL;
|
||||
BEGIN
|
||||
k2 := verse.hcc_const_k2( ylimit , yasymptote );
|
||||
k3 := verse.hcc_const_k3( xmax , ymax , xlimit , ylimit , yasymptote );
|
||||
RETURN yasymptote + k2 * ( 1 - verse.sigma( ( k3 * ( x - xlimit ) ) )::REAL );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Happiness curve
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.happiness_curve( x REAL , ymin REAL , xmax REAL , ymax REAL , xlimit REAL , ylimit REAL , yasymptote REAL )
|
||||
RETURNS REAL
|
||||
STRICT IMMUTABLE SECURITY INVOKER
|
||||
AS $$
|
||||
SELECT (CASE
|
||||
WHEN $1 < $3 THEN
|
||||
verse.hcc_part_1( $1 , $2 , $4 , $3 )
|
||||
WHEN $1 < $5 THEN
|
||||
verse.hcc_part_2( $1 , $3 , $4 , $5 , $6 )
|
||||
ELSE
|
||||
verse.hcc_part_3( $1 , $3 , $4 , $5 , $6 , $7 )
|
||||
END)
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Happiness computation
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.compute_happiness( population REAL , workers REAL , defence REAL , empsize INT )
|
||||
RETURNS REAL
|
||||
STRICT STABLE SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
whappiness REAL;
|
||||
dhappiness REAL;
|
||||
shappiness REAL;
|
||||
BEGIN
|
||||
-- Work-related happiness
|
||||
whappiness := verse.happiness_curve(
|
||||
( workers / population )::REAL ,
|
||||
sys.get_constant( 'game.happiness.noEmployment' ) , 1.0 , 1.0 ,
|
||||
sys.get_constant( 'game.happiness.employmentLimit' ) , 0.5 , 0
|
||||
);
|
||||
|
||||
-- Defence-related happiness
|
||||
dhappiness := verse.happiness_curve(
|
||||
( sys.get_constant( 'game.happiness.popPerDefencePoint' ) * defence / population )::REAL ,
|
||||
sys.get_constant( 'game.happiness.noDefence' ) , 1.0 , 1.0 ,
|
||||
sys.get_constant( 'game.happiness.defenceLimit' ) , 0.5 , 0
|
||||
);
|
||||
|
||||
-- Influence of empire size
|
||||
shappiness := verse.happiness_curve(
|
||||
( empsize::REAL / sys.get_constant( 'game.happiness.idealEmpireSize' ) )::REAL ,
|
||||
sys.get_constant( 'game.happiness.smallEmpire' ) , 1.0 , 1.0 ,
|
||||
sys.get_constant( 'game.happiness.eSizeLimit' ) , 0.5 , 0
|
||||
);
|
||||
|
||||
RETURN ( shappiness * ( whappiness + dhappiness ) / 2.0 )::REAL;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Production adjustment
|
||||
--
|
||||
CREATE OR REPLACE FUNCTION verse.adjust_production( prod REAL , happiness REAL )
|
||||
RETURNS REAL
|
||||
STRICT IMMUTABLE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
SELECT ( CASE
|
||||
WHEN $2 < sys.get_constant( 'game.happiness.strike' ) THEN
|
||||
( $1 * ( 1 - ( $2 / sys.get_constant( 'game.happiness.strike' ) ) ) )::REAL
|
||||
ELSE
|
||||
$1
|
||||
END );
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
--
|
||||
-- Income computation
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.compute_income( population REAL , happiness REAL , cashprod REAL )
|
||||
RETURNS REAL
|
||||
STRICT STABLE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
base REAL;
|
||||
badj REAL;
|
||||
cprod REAL;
|
||||
BEGIN
|
||||
badj := ( 1 - verse.adjust_production( 1.0 , happiness ) ) * sys.get_constant( 'game.work.strikeEffect' );
|
||||
base := floor( population ) * sys.get_constant( 'game.work.population' ) * ( 1 - badj );
|
||||
cprod := verse.adjust_production( cashprod , happiness ) * sys.get_constant( 'game.work.factory' );
|
||||
RETURN cprod + base;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
|
@ -0,0 +1,394 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Universe management functions and views
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Obtains a planet's raw production
|
||||
--
|
||||
-- Parameters:
|
||||
-- pid Planet identifier
|
||||
-- pt Production type
|
||||
--
|
||||
-- Returns:
|
||||
-- the planet's raw production of the specified type
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.get_raw_production( pid INT , pt building_output_type )
|
||||
RETURNS REAL
|
||||
STRICT STABLE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
rv REAL;
|
||||
BEGIN
|
||||
SELECT INTO rv SUM( b.amount * d.output )::REAL
|
||||
FROM verse.planet_buildings b
|
||||
INNER JOIN tech.buildings d
|
||||
ON d.buildable_id = b.building_id AND d.output_type = pt
|
||||
WHERE b.planet_id = pid;
|
||||
IF rv IS NULL THEN
|
||||
rv := 0;
|
||||
END IF;
|
||||
RETURN rv;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
--
|
||||
-- Map view
|
||||
--
|
||||
|
||||
CREATE VIEW verse.map_view
|
||||
AS SELECT s.x AS x , s.y AS y , p.orbit AS orbit ,
|
||||
n.id AS id , p.picture AS picture , n.name AS name ,
|
||||
ep.empire_id AS owner ,
|
||||
a.id AS alliance_id , a.tag AS tag
|
||||
FROM verse.planets p
|
||||
INNER JOIN verse.systems s
|
||||
ON s.id = p.system_id
|
||||
INNER JOIN naming.map_names n
|
||||
ON n.id = p.name_id
|
||||
LEFT OUTER JOIN emp.planets ep
|
||||
ON ep.planet_id = p.name_id
|
||||
LEFT OUTER JOIN emp.alliance_members am
|
||||
ON ep.empire_id = am.empire_id AND NOT am.is_pending
|
||||
LEFT OUTER JOIN emp.alliances a
|
||||
ON a.id = am.alliance_id
|
||||
ORDER BY s.x , s.y , p.orbit;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- View of planets that can be assigned to players
|
||||
--
|
||||
|
||||
CREATE VIEW verse.available_planets
|
||||
AS SELECT p.name_id AS name_id
|
||||
FROM verse.planets p
|
||||
INNER JOIN verse.planet_happiness ph
|
||||
ON ph.planet_id = p.name_id
|
||||
LEFT OUTER JOIN emp.planets ep
|
||||
ON ep.planet_id = p.name_id
|
||||
LEFT OUTER JOIN fleets.fleets f
|
||||
ON f.location_id = p.name_id
|
||||
WHERE ep.empire_id IS NULL AND ph.target > 0.5
|
||||
AND verse.get_raw_production( p.name_id , 'DEF'::building_output_type ) > 0
|
||||
AND verse.get_raw_production( p.name_id , 'WORK'::building_output_type ) > 0
|
||||
AND ph.current / p.population > sys.get_constant( 'game.happiness.strike' )
|
||||
GROUP BY p.name_id HAVING count(f.*) = 0;
|
||||
|
||||
|
||||
--
|
||||
-- Returns a random free planet, locked for update
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.get_random_planet( )
|
||||
RETURNS INT
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
SELECT name_id
|
||||
FROM verse.planets p
|
||||
INNER JOIN verse.available_planets
|
||||
USING ( name_id )
|
||||
ORDER BY random() LIMIT 1
|
||||
FOR UPDATE OF p;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Obtains a planet's upkeep
|
||||
--
|
||||
-- Parameters:
|
||||
-- pid Planet identifier
|
||||
--
|
||||
-- Returns:
|
||||
-- the planet's current upkeep
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.get_planet_upkeep( pid INT )
|
||||
RETURNS REAL
|
||||
STRICT STABLE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
rv REAL;
|
||||
BEGIN
|
||||
SELECT INTO rv SUM( b.amount * d.upkeep )::REAL
|
||||
FROM verse.planet_buildings b
|
||||
INNER JOIN tech.buildables d
|
||||
ON d.name_id = b.building_id
|
||||
WHERE b.planet_id = pid;
|
||||
IF rv IS NULL THEN
|
||||
rv := 0;
|
||||
END IF;
|
||||
RETURN rv;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates a planet
|
||||
--
|
||||
-- Parameters:
|
||||
-- sid Stellar system ID
|
||||
-- o Orbit number
|
||||
-- ipop Initial population
|
||||
-- npics Amount of planet pictures
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.create_planet( sid INT , o INT , ipop REAL , npics INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
pnid INT;
|
||||
bworkers INT;
|
||||
bpp INT;
|
||||
uid BIGINT;
|
||||
utp update_type;
|
||||
happiness REAL;
|
||||
BEGIN
|
||||
-- Planet name and planet
|
||||
pnid := naming.create_map_name( 'P' );
|
||||
INSERT INTO verse.planets ( name_id , system_id , orbit , picture , population )
|
||||
VALUES ( pnid , sid , o , 1 + floor( random() * npics ) , ipop );
|
||||
|
||||
-- Create build queues
|
||||
INSERT INTO verse.bld_queues( planet_id , money , work )
|
||||
VALUES ( pnid , 0 , 0 );
|
||||
INSERT INTO verse.mil_queues( planet_id , money , work )
|
||||
VALUES ( pnid , 0 , 0 );
|
||||
|
||||
-- Insert initial buildings
|
||||
SELECT INTO bworkers SUM( d.workers ) FROM tech.buildings_view d
|
||||
INNER JOIN tech.basic_buildables b USING( name_id );
|
||||
bpp := floor( 0.5 * ipop / bworkers );
|
||||
INSERT INTO verse.planet_buildings ( planet_id , building_id , amount , damage )
|
||||
SELECT pnid , d.name_id , bpp , 0.0 FROM tech.buildings_view d
|
||||
INNER JOIN tech.basic_buildables b USING( name_id );
|
||||
|
||||
-- Compute initial happiness
|
||||
happiness := verse.compute_happiness(
|
||||
ipop , bpp * bworkers ,
|
||||
verse.get_raw_production( pnid , 'DEF'::building_output_type ) ,
|
||||
0
|
||||
);
|
||||
INSERT INTO verse.planet_happiness ( planet_id , current , target )
|
||||
VALUES ( pnid , ipop * happiness , happiness );
|
||||
|
||||
-- Compute initial income and upkeep
|
||||
INSERT INTO verse.planet_money ( planet_id , income , upkeep )
|
||||
VALUES ( pnid , verse.compute_income(
|
||||
ipop , happiness ,
|
||||
verse.get_raw_production( pnid , 'CASH'::building_output_type )
|
||||
) , verse.get_planet_upkeep( pnid ) );
|
||||
|
||||
-- Add planet update records
|
||||
FOR utp IN SELECT x FROM unnest( enum_range( NULL::update_type ) ) AS x
|
||||
WHERE x::text LIKE 'PLANET_%'
|
||||
LOOP
|
||||
INSERT INTO sys.updates( gu_type )
|
||||
VALUES ( utp )
|
||||
RETURNING id INTO uid;
|
||||
INSERT INTO verse.updates ( update_id , planet_id )
|
||||
VALUES ( uid , pnid );
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates a stellar system
|
||||
--
|
||||
-- Parameters:
|
||||
-- sx, sy Coordinates
|
||||
-- ipop Initial population of planets
|
||||
-- npics Amount of planet pictures
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.create_system( sx INT , sy INT , ipop REAL , npics INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
sid INT;
|
||||
orbit INT;
|
||||
BEGIN
|
||||
-- Create system
|
||||
INSERT INTO verse.systems ( x , y )
|
||||
VALUES ( sx , sy )
|
||||
RETURNING id INTO sid;
|
||||
|
||||
-- Create planets
|
||||
FOR orbit IN 1 .. 5
|
||||
LOOP
|
||||
PERFORM verse.create_planet( sid , orbit , ipop , npics );
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Generate multiple systems at the specified coordinates
|
||||
--
|
||||
-- Parameters:
|
||||
-- (x0,y0)-(x1,y1) Area to generate
|
||||
-- ipop Initial population
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.create_systems( x0 INT , y0 INT , x1 INT , y1 INT , ipop REAL )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
x INT;
|
||||
y INT;
|
||||
npics INT;
|
||||
BEGIN
|
||||
npics := floor( sys.get_constant( 'game.universe.pictures' ) );
|
||||
FOR x IN x0 .. x1
|
||||
LOOP
|
||||
FOR y IN y0 .. y1
|
||||
LOOP
|
||||
PERFORM verse.create_system( x , y , ipop , npics );
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Generate the initial universe
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.generate_initial_universe( )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
sz INT;
|
||||
pop REAL;
|
||||
npics INT;
|
||||
BEGIN
|
||||
sz := floor( sys.get_constant( 'game.universe.initialSize' ) );
|
||||
pop := sys.get_constant( 'game.universe.initialPopulation' );
|
||||
PERFORM verse.create_systems( -sz , -sz , sz , sz , pop );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Expand the universe
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.expand_universe( )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
min_x INT;
|
||||
max_x INT;
|
||||
min_y INT;
|
||||
max_y INT;
|
||||
x_size INT;
|
||||
y_size INT;
|
||||
x_axis BOOLEAN;
|
||||
posit BOOLEAN;
|
||||
x0 INT;
|
||||
y0 INT;
|
||||
x1 INT;
|
||||
y1 INT;
|
||||
pop REAL;
|
||||
BEGIN
|
||||
-- Get current bounds
|
||||
SELECT INTO min_x , max_x , min_y , max_y
|
||||
MIN(x) , MAX(x) , MIN(y) , MAX(y)
|
||||
FROM verse.systems;
|
||||
x_size := 1 + max_x - min_x;
|
||||
y_size := 1 + max_y - min_y;
|
||||
|
||||
-- Find out which axis/direction to use
|
||||
x_axis := ( x_size = y_size );
|
||||
IF x_axis THEN
|
||||
posit := ( max_x = -min_x );
|
||||
ELSE
|
||||
posit := ( max_y = -min_y );
|
||||
END IF;
|
||||
|
||||
-- Compute area coordinates
|
||||
IF x_axis THEN
|
||||
x0 := ( CASE posit WHEN TRUE THEN max_x + 1 ELSE min_x - 1 END );
|
||||
x1 := x0;
|
||||
y0 := min_y;
|
||||
y1 := max_y;
|
||||
ELSE
|
||||
y0 := ( CASE posit WHEN TRUE THEN max_y + 1 ELSE min_y - 1 END );
|
||||
y1 := y0;
|
||||
x0 := min_x;
|
||||
x1 := max_x;
|
||||
END IF;
|
||||
|
||||
-- Get average population and generate new systems
|
||||
SELECT INTO pop AVG( population ) FROM verse.planets;
|
||||
PERFORM verse.create_systems( x0 , y0 , x1 , y1 , pop );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Universe generator function
|
||||
--
|
||||
-- Called by the game engine; generate the initial universe if it is empty, or expand it
|
||||
-- if the ratio of available planets is too low.
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.generate( )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
p_count INT;
|
||||
f_ratio REAL;
|
||||
BEGIN
|
||||
-- Get total planet count
|
||||
SELECT INTO p_count 5 * count(*)
|
||||
FROM verse.systems;
|
||||
|
||||
-- Empty universe -> initialise
|
||||
IF p_count = 0 THEN
|
||||
PERFORM verse.generate_initial_universe( );
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Get available planets ratio
|
||||
SELECT INTO f_ratio count(*)::REAL / p_count::REAL
|
||||
FROM verse.available_planets;
|
||||
|
||||
-- Expand universe if required
|
||||
IF f_ratio < sys.get_constant( 'game.universe.minFreeRatio' ) THEN
|
||||
PERFORM verse.expand_universe( );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION verse.generate() TO :dbuser;
|
File diff suppressed because it is too large
Load diff
|
@ -0,0 +1,313 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- User sessions functions
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- MAIN SESSION VIEW --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
|
||||
|
||||
CREATE VIEW users.sessions
|
||||
AS SELECT s.* , e.ended , e.end_type , c.name AS client_name , c.exclusive
|
||||
FROM users.session_starts s
|
||||
INNER JOIN defs.session_clients c ON c.id = s.client_id
|
||||
LEFT OUTER JOIN users.session_ends e ON s.id = e.id
|
||||
ORDER BY e.ended DESC NULLS FIRST , s.started DESC;
|
||||
|
||||
GRANT SELECT ON users.sessions TO :dbuser;
|
||||
|
||||
|
||||
CREATE VIEW users.last_session
|
||||
AS SELECT credentials_id , max( id ) AS session_id
|
||||
FROM users.session_starts
|
||||
GROUP BY credentials_id;
|
||||
|
||||
|
||||
CREATE VIEW users.last_online
|
||||
AS SELECT ls.credentials_id , ( CASE WHEN se.id IS NULL THEN now() ELSE se.ended END ) AS t
|
||||
FROM users.last_session ls
|
||||
LEFT OUTER JOIN users.session_ends se ON se.id = ls.session_id;
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- SESSION MANAGEMENT FUNCTIONS --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
|
||||
|
||||
--
|
||||
-- Marks all active sessions as terminated due to server restart
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION users.sessions_server_restart( )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
INSERT INTO users.session_ends( id , end_type )
|
||||
SELECT s.id , 'SERVER'::session_termination_type
|
||||
FROM users.session_starts s
|
||||
LEFT OUTER JOIN users.session_ends e USING ( id )
|
||||
WHERE e.id IS NULL;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION users.sessions_server_restart( ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Registers a session's initialisation
|
||||
--
|
||||
-- Parameters:
|
||||
-- c_id Credentials identifier
|
||||
-- s_name Session name
|
||||
-- c_type Client type name
|
||||
-- s_addr Session address
|
||||
--
|
||||
-- Returns:
|
||||
-- s_id Session identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION users.sessions_login( c_id INT , s_name TEXT , c_type TEXT , s_addr TEXT , OUT s_id BIGINT )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
cl_id INT;
|
||||
excl BOOLEAN;
|
||||
as_id BIGINT;
|
||||
as_nm TEXT;
|
||||
BEGIN
|
||||
-- Get client type parameters
|
||||
SELECT INTO cl_id , excl id , exclusive
|
||||
FROM defs.session_clients
|
||||
WHERE name = c_type;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
RAISE EXCEPTION 'Client session type "%" not found' , c_type;
|
||||
END IF;
|
||||
|
||||
-- Close all active, exclusive sessions from the same user if the new session is exclusive
|
||||
IF excl
|
||||
THEN
|
||||
FOR as_id , as_nm IN SELECT s.id , s.session
|
||||
FROM users.session_starts s
|
||||
INNER JOIN defs.session_clients c
|
||||
ON s.client_id = c.id AND c.exclusive
|
||||
LEFT OUTER JOIN users.session_ends e ON s.id = e.id
|
||||
WHERE s.credentials_id = c_id AND e.id IS NULL
|
||||
FOR UPDATE OF s
|
||||
LOOP
|
||||
PERFORM users.write_log( c_id , 'WARNING'::log_level , 'Terminating exclusive session "' || as_nm
|
||||
|| '" due to new exlusive session' );
|
||||
INSERT INTO users.session_ends ( id , end_type )
|
||||
VALUES ( as_id , 'EXCLUSIVE'::session_termination_type );
|
||||
END LOOP;
|
||||
END IF;
|
||||
|
||||
-- Add new session
|
||||
INSERT INTO users.session_starts ( credentials_id , client_id , session , from_address )
|
||||
VALUES ( c_id , cl_id , s_name , s_addr )
|
||||
RETURNING id INTO s_id;
|
||||
PERFORM users.write_log( c_id , 'DEBUG'::log_level , 'Logged in from ' || s_addr
|
||||
|| ' with client ' || c_type || '; session #' || s_id );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION users.sessions_login( INT , TEXT , TEXT , TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Terminates a session
|
||||
--
|
||||
-- Parameters:
|
||||
-- s_id Session identifier
|
||||
-- e_type Session end type
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION users.sessions_terminate( s_id BIGINT , e_type session_termination_type )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
c_id INT;
|
||||
BEGIN
|
||||
-- Get user identifier
|
||||
SELECT INTO c_id s.credentials_id
|
||||
FROM users.session_starts s
|
||||
LEFT OUTER JOIN users.session_ends e USING ( id )
|
||||
WHERE s.id = s_id AND e.id IS NULL
|
||||
FOR UPDATE OF s;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Terminate session
|
||||
INSERT INTO users.session_ends ( id , end_type )
|
||||
VALUES ( s_id , e_type );
|
||||
PERFORM users.write_log( c_id , 'DEBUG'::log_level , 'Session #' || s_id
|
||||
|| ' ended, termination type: ' || e_type );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION users.sessions_terminate( BIGINT , session_termination_type ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- INACTIVITY CHECKS AND SESSION CLEAN-UP --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
|
||||
--
|
||||
-- User account record, used to send e-mails
|
||||
--
|
||||
|
||||
CREATE TYPE inactive_account_record AS (
|
||||
id INT ,
|
||||
address TEXT ,
|
||||
language TEXT
|
||||
);
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Checks for accounts that should receive an inactivity warning e-mail
|
||||
--
|
||||
-- Returns:
|
||||
-- A set of user account records
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION users.check_inactivity_emails()
|
||||
RETURNS SETOF inactive_account_record
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
in_units BIGINT;
|
||||
in_mail BIGINT;
|
||||
in_time INTERVAL;
|
||||
a_rec inactive_account_record;
|
||||
BEGIN
|
||||
in_units := floor( sys.get_constant( 'accounts.inactivity.units' ) );
|
||||
in_mail := floor( sys.get_constant( 'accounts.inactivity.warningMail' ) );
|
||||
in_time := ( (in_units * in_mail ) || 's' )::INTERVAL;
|
||||
|
||||
FOR a_rec IN SELECT cr.address_id AS id , ad.address , lg.language
|
||||
FROM users.last_online lo
|
||||
INNER JOIN users.credentials cr ON lo.credentials_id = cr.address_id
|
||||
INNER JOIN users.addresses ad ON ad.id = cr.address_id
|
||||
INNER JOIN defs.languages lg ON lg.id = cr.language_id
|
||||
INNER JOIN users.active_accounts aa ON aa.credentials_id = lo.credentials_id
|
||||
LEFT OUTER JOIN users.vacations vac ON vac.account_id = lo.credentials_id
|
||||
LEFT OUTER JOIN users.inactivity_emails im ON im.account_id = lo.credentials_id
|
||||
WHERE vac IS NULL AND im IS NULL AND now() - lo.t > in_time
|
||||
FOR UPDATE OF cr , aa , ad
|
||||
LOOP
|
||||
INSERT INTO users.inactivity_emails ( account_id ) VALUES ( a_rec.id );
|
||||
PERFORM users.write_log( a_rec.id , 'INFO'::log_level , 'Sending inactivity warning e-mail' );
|
||||
RETURN NEXT a_rec;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION users.check_inactivity_emails() TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Removes inactivity e-mail records when users have logged on *after* the e-mail was sent
|
||||
-- Disables inactive accounts, and lists them
|
||||
--
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION users.check_inactivity( )
|
||||
RETURNS SETOF inactive_account_record
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
in_units BIGINT;
|
||||
in_drop BIGINT;
|
||||
in_time INTERVAL;
|
||||
a_rec RECORD;
|
||||
r_rec inactive_account_record;
|
||||
BEGIN
|
||||
in_units := floor( sys.get_constant( 'accounts.inactivity.units' ) );
|
||||
in_drop := floor( sys.get_constant( 'accounts.inactivity.deletion' ) );
|
||||
in_time := ( (in_units * in_drop ) || 's' )::INTERVAL;
|
||||
|
||||
-- Delete inactivity email records for players who've logged in since the mail was sent
|
||||
DELETE FROM users.inactivity_emails WHERE account_id IN (
|
||||
SELECT lo.credentials_id
|
||||
FROM users.last_online lo
|
||||
INNER JOIN users.inactivity_emails im
|
||||
ON im.account_id = lo.credentials_id AND im.mail_sent <= lo.t
|
||||
);
|
||||
|
||||
-- Disable inactive user accounts
|
||||
FOR a_rec IN SELECT cr.address_id AS id , ad.address , lg.language , e.name_id AS e_id
|
||||
FROM users.inactivity_emails im
|
||||
INNER JOIN users.credentials cr ON im.account_id = cr.address_id
|
||||
INNER JOIN users.active_accounts aa ON aa.credentials_id = im.account_id
|
||||
INNER JOIN users.addresses ad ON ad.id = cr.address_id
|
||||
INNER JOIN defs.languages lg ON lg.id = cr.language_id
|
||||
INNER JOIN naming.empire_names en ON en.owner_id = cr.address_id
|
||||
INNER JOIN emp.empires e ON e.name_id = en.id
|
||||
WHERE now() - im.mail_sent > in_time
|
||||
FOR UPDATE OF cr , aa , ad , lg , en , e
|
||||
LOOP
|
||||
PERFORM users.write_log( a_rec.id , 'INFO'::log_level , 'Disabling account due to inactivity' );
|
||||
PERFORM emp.delete_empire( a_rec.e_id );
|
||||
DELETE FROM users.active_accounts WHERE credentials_id = a_rec.id;
|
||||
INSERT INTO users.inactive_accounts ( credentials_id , since , status )
|
||||
VALUES ( a_rec.id , now() - '1s'::INTERVAL , 'PROCESSED' );
|
||||
r_rec := ( a_rec.id , a_rec.address, a_rec.language );
|
||||
RETURN NEXT r_rec;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION users.check_inactivity() TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Destroys old, inactive accounts
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION users.delete_old_accounts( )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DELETE FROM users.addresses WHERE id IN (
|
||||
SELECT ia.credentials_id
|
||||
FROM users.inactive_accounts ia
|
||||
LEFT OUTER JOIN admin.admin_credentials ac USING ( credentials_id )
|
||||
LEFT OUTER JOIN admin.administrators ad ON ad.id = ac.administrator_id
|
||||
WHERE now() - since >= '6 months'::INTERVAL AND ( ad IS NULL OR ad.privileges = 0 )
|
||||
);
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION users.delete_old_accounts() TO :dbuser;
|
|
@ -0,0 +1,84 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Buildings views and management functions
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Construct buildings on a planet
|
||||
--
|
||||
-- Parameters:
|
||||
-- pid Planet identifier
|
||||
-- bid Building type
|
||||
-- bcnt Amount of buildings
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.do_construct_buildings( pid INT , bid INT , bcnt INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
BEGIN
|
||||
LOOP
|
||||
UPDATE verse.planet_buildings
|
||||
SET amount = amount + bcnt
|
||||
WHERE planet_id = pid AND building_id = bid;
|
||||
EXIT WHEN FOUND;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO verse.planet_buildings( planet_id , building_id , amount , damage )
|
||||
VALUES( pid , bid , bcnt , 0 );
|
||||
EXIT;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing, try updating again.
|
||||
END;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Destroy buildings on a planet
|
||||
--
|
||||
-- Parameters:
|
||||
-- pid Planet identifier
|
||||
-- bid Building type
|
||||
-- bcnt Amount of buildings
|
||||
--
|
||||
-- Returns:
|
||||
-- amount of buildings that were destroyed
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.do_destroy_buildings( pid INT , bid INT , bcnt INT )
|
||||
RETURNS INT
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
tmp INT;
|
||||
BEGIN
|
||||
UPDATE verse.planet_buildings
|
||||
SET amount = amount - bcnt
|
||||
WHERE planet_id = pid AND building_id = bid;
|
||||
|
||||
IF FOUND THEN
|
||||
RETURN bcnt;
|
||||
END IF;
|
||||
|
||||
RETURN 0;
|
||||
EXCEPTION
|
||||
WHEN check_violation THEN
|
||||
SELECT INTO tmp amount FROM verse.planet_buildings
|
||||
WHERE planet_id = pid AND building_id = bid
|
||||
FOR UPDATE;
|
||||
UPDATE verse.planet_buildings
|
||||
SET amount = 0
|
||||
WHERE planet_id = pid AND building_id = bid;
|
||||
RETURN tmp;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
|
@ -0,0 +1,107 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- System status functions
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Enter maintenance mode
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- reason_txt Maintenance reason
|
||||
-- duration Expected duration (minutes)
|
||||
--
|
||||
-- Returns:
|
||||
-- success TRUE on success, FALSE if the system was already in maintenance mode
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.enter_maintenance_mode( IN a_id INT , IN reason_txt TEXT , IN duration INT , OUT success BOOLEAN )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
BEGIN
|
||||
UPDATE sys.status
|
||||
SET maintenance_start = NOW( ) ,
|
||||
maintenance_end = NOW( ) + ( duration || 'm' )::INTERVAL ,
|
||||
maintenance_text = reason_txt
|
||||
WHERE maintenance_start IS NULL;
|
||||
success := FOUND;
|
||||
IF success
|
||||
THEN
|
||||
PERFORM admin.write_log( a_id , 'WARNING'::log_level , 'enabled maintenance mode for ' ||
|
||||
duration || ' minutes; reason: ' || reason_txt );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.enter_maintenance_mode( INT , TEXT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Extend maintenance mode duration
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- ext_duration Expected extended duration (minutes)
|
||||
--
|
||||
-- Returns:
|
||||
-- success TRUE on success, FALSE if the system was not in maintenance mode
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.extend_maintenance_mode( IN a_id INT , IN ext_duration INT , OUT success BOOLEAN )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
BEGIN
|
||||
UPDATE sys.status
|
||||
SET maintenance_end = NOW( ) + ( ext_duration || 'm' )::INTERVAL
|
||||
WHERE maintenance_start IS NOT NULL;
|
||||
success := FOUND;
|
||||
IF success
|
||||
THEN
|
||||
PERFORM admin.write_log( a_id , 'WARNING'::log_level , 'extended maintenance mode duration by ' ||
|
||||
ext_duration || ' minutes' );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.extend_maintenance_mode( INT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Exit maintenance mode
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
--
|
||||
-- Returns:
|
||||
-- success TRUE on success, FALSE if the system was not in maintenance mode
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.exit_maintenance_mode( IN a_id INT , OUT success BOOLEAN )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
BEGIN
|
||||
UPDATE sys.status
|
||||
SET maintenance_start = NULL ,
|
||||
maintenance_end = NULL ,
|
||||
maintenance_text = NULL
|
||||
WHERE maintenance_start IS NOT NULL;
|
||||
success := FOUND;
|
||||
IF success
|
||||
THEN
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'terminated maintenance mode' );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.exit_maintenance_mode( INT ) TO :dbuser;
|
||||
|
|
@ -0,0 +1,283 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Preference definitions and values functions
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Preferences view
|
||||
--
|
||||
|
||||
CREATE VIEW users.preferences_view
|
||||
AS SELECT acc.credentials_id AS account_id ,
|
||||
grp.name AS group_name ,
|
||||
grpn.translated_string AS group_i18n_name ,
|
||||
pref.name AS pref_name ,
|
||||
prefn.translated_string AS pref_i18n_name ,
|
||||
prefd.translated_string AS pref_i18n_description ,
|
||||
pref.java_type AS pref_type ,
|
||||
( CASE ( upr.pref_value IS NULL )
|
||||
WHEN TRUE THEN pref.default_value
|
||||
ELSE upr.pref_value
|
||||
END ) AS value
|
||||
FROM users.active_accounts acc
|
||||
INNER JOIN users.credentials cred
|
||||
ON cred.address_id = acc.credentials_id
|
||||
CROSS JOIN defs.preference_definitions pref
|
||||
INNER JOIN defs.preference_groups grp
|
||||
ON grp.id = pref.group_id
|
||||
INNER JOIN defs.translations grpn
|
||||
ON grpn.lang_id = cred.language_id AND grpn.string_id = grp.display_id
|
||||
INNER JOIN defs.translations prefn
|
||||
ON prefn.lang_id = cred.language_id AND prefn.string_id = pref.disp_name_id
|
||||
INNER JOIN defs.translations prefd
|
||||
ON prefd.lang_id = cred.language_id AND prefd.string_id = pref.disp_desc_id
|
||||
LEFT OUTER JOIN users.preferences upr
|
||||
ON upr.definition_id = pref.id AND upr.account_id = acc.credentials_id
|
||||
ORDER BY acc.credentials_id , grp.name , pref.name;
|
||||
|
||||
GRANT SELECT ON users.preferences_view TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Definitions view
|
||||
--
|
||||
|
||||
CREATE VIEW defs.preferences_view
|
||||
AS SELECT grp.name AS group_name , gds.name AS group_display , pref.name AS name ,
|
||||
pns.name AS d_name , pds.name AS d_desc ,
|
||||
pref.java_type AS java_type , pref.default_value AS default_value
|
||||
FROM defs.preference_definitions pref
|
||||
INNER JOIN defs.preference_groups grp ON grp.id = pref.group_id
|
||||
INNER JOIN defs.strings gds ON gds.id = grp.display_id
|
||||
INNER JOIN defs.strings pns ON pns.id = pref.disp_name_id
|
||||
INNER JOIN defs.strings pds ON pds.id = pref.disp_desc_id
|
||||
ORDER BY grp.name , pref.name;
|
||||
|
||||
GRANT SELECT ON defs.preferences_view TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Group registration
|
||||
--
|
||||
-- Parameters:
|
||||
-- g_name Group name
|
||||
-- g_display Display name identifier
|
||||
--
|
||||
-- Returns:
|
||||
-- success Whether the operation was successful or not
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION defs.uoc_preference_group( g_name TEXT , g_display TEXT , OUT success BOOLEAN )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
did INT;
|
||||
BEGIN
|
||||
SELECT INTO did id FROM defs.strings WHERE name = g_display;
|
||||
success := FOUND;
|
||||
IF NOT success THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
LOOP
|
||||
UPDATE defs.preference_groups SET display_id = did
|
||||
WHERE name = g_name;
|
||||
EXIT WHEN FOUND;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO defs.preference_groups (name , display_id)
|
||||
VALUES (g_name , did);
|
||||
EXIT;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing.
|
||||
END;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION defs.uoc_preference_group( TEXT , TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Preference definition registration
|
||||
--
|
||||
-- Parameters:
|
||||
-- g_name Group name
|
||||
-- p_name Preference name
|
||||
-- d_name Display name identifier
|
||||
-- d_desc Display description identifier
|
||||
-- j_type Java type name
|
||||
-- d_val Serialised default value
|
||||
--
|
||||
-- Returns:
|
||||
-- err_code Error code
|
||||
-- 0 on success
|
||||
-- 1 if the group is missing
|
||||
-- 2 if one of the strings is missing
|
||||
-- 3 if the definition exists but has a different type
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION defs.uoc_preference( g_name TEXT , p_name TEXT , d_name TEXT , d_desc TEXT , j_type TEXT , d_val TEXT,
|
||||
OUT err_code INT )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
g_id INT;
|
||||
n_id INT;
|
||||
d_id INT;
|
||||
p_id INT;
|
||||
o_type TEXT;
|
||||
BEGIN
|
||||
-- Get group identifier
|
||||
SELECT INTO g_id id FROM defs.preference_groups WHERE name = g_name;
|
||||
IF NOT FOUND THEN
|
||||
err_code := 1;
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Get strings
|
||||
SELECT INTO n_id id FROM defs.strings WHERE name = d_name;
|
||||
SELECT INTO d_id id FROM defs.strings WHERE name = d_desc;
|
||||
IF n_id IS NULL OR d_id IS NULL THEN
|
||||
err_code := 2;
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
LOOP
|
||||
-- Try updating
|
||||
SELECT INTO p_id , o_type id , java_type
|
||||
FROM defs.preference_definitions
|
||||
WHERE name = p_name
|
||||
FOR UPDATE;
|
||||
IF FOUND THEN
|
||||
-- Make sure the type didn't change
|
||||
IF o_type <> j_type THEN
|
||||
err_code := 3;
|
||||
ELSE
|
||||
err_code := 0;
|
||||
UPDATE defs.preference_definitions
|
||||
SET disp_name_id = n_id , disp_desc_id = d_id , group_id = g_id
|
||||
WHERE id = p_id;
|
||||
END IF;
|
||||
EXIT;
|
||||
END IF;
|
||||
|
||||
-- Try inserting
|
||||
BEGIN
|
||||
INSERT INTO defs.preference_definitions (group_id , name , disp_name_id , disp_desc_id , java_type , default_value )
|
||||
VALUES ( g_id , p_name , n_id , d_id , j_type , d_val );
|
||||
err_code := 0;
|
||||
EXIT;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION defs.uoc_preference( TEXT , TEXT , TEXT , TEXT , TEXT , TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Set a preference's default value
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- p_name Preference name
|
||||
-- p_val Preference default value
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION defs.set_preference_default( a_id INT , p_name TEXT , p_val TEXT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
BEGIN
|
||||
UPDATE defs.preference_definitions SET default_value = p_val WHERE name = p_name;
|
||||
IF FOUND
|
||||
THEN
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Changed default value of preference "' || p_name
|
||||
|| '" to "' || p_val || '"' );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION defs.set_preference_default( INT , TEXT , TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Resets an account's preferences
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Account identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION users.reset_preferences( a_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
BEGIN
|
||||
DELETE FROM users.preferences WHERE account_id = a_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION users.reset_preferences( INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Sets a preference
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Account identifier
|
||||
-- p_name Preference name
|
||||
-- p_val New value
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION users.set_preference( a_id INT , p_name TEXT , p_val TEXT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
p_id INT;
|
||||
BEGIN
|
||||
-- Get preference identifier
|
||||
SELECT INTO p_id id FROM defs.preference_definitions
|
||||
WHERE name = p_name;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Update or add preference
|
||||
LOOP
|
||||
UPDATE users.preferences SET pref_value = p_val
|
||||
WHERE account_id = a_id AND definition_id = p_id;
|
||||
EXIT WHEN FOUND;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO users.preferences( account_id , definition_id , pref_value )
|
||||
VALUES( a_id , p_id , p_val );
|
||||
EXIT;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION users.set_preference( INT , TEXT , TEXT ) TO :dbuser;
|
|
@ -0,0 +1,58 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Map display functions and related types
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
-- Map entry
|
||||
CREATE TYPE map_entry_type AS (
|
||||
x INT ,
|
||||
y INT ,
|
||||
orbit INT ,
|
||||
id INT ,
|
||||
picture INT ,
|
||||
name TEXT ,
|
||||
tag TEXT ,
|
||||
display empire_relation_type
|
||||
);
|
||||
|
||||
|
||||
--
|
||||
-- Generates the map from an empire's point of view
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id the empire viewing the map
|
||||
-- min_x minimal X coordinate
|
||||
-- min_y minimal Y coordinate
|
||||
-- max_x maximal X coordinate
|
||||
-- max_y maximal Y coordinate
|
||||
--
|
||||
-- Returns:
|
||||
-- a set of map entries
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION verse.get_map( e_id INT , min_x INT , min_y INT , max_x INT , max_y INT )
|
||||
RETURNS SETOF map_entry_type
|
||||
STRICT STABLE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
SELECT mv.x AS x , mv.y AS y , mv.orbit AS orbit , mv.id AS id , mv.picture AS picture ,
|
||||
mv.name AS name , mv.tag AS tag ,
|
||||
(CASE
|
||||
WHEN mv.owner = $1 THEN 'OWN'
|
||||
WHEN mv.alliance_id IS NOT NULL AND mv.alliance_id = ea.alliance_id THEN 'ALLIED'
|
||||
WHEN en.alliance_id IS NOT NULL THEN 'ENEMY'
|
||||
ELSE NULL
|
||||
END )::empire_relation_type AS display
|
||||
FROM verse.map_view mv
|
||||
LEFT OUTER JOIN emp.alliance_members ea
|
||||
ON ea.empire_id = $1 AND NOT is_pending
|
||||
LEFT OUTER JOIN emp.enemy_alliances en
|
||||
ON en.empire_id = $1 AND en.alliance_id = mv.alliance_id
|
||||
WHERE x BETWEEN $2 AND $4 AND y BETWEEN $3 AND $5;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION verse.get_map( INT , INT , INT , INT , INT ) TO :dbuser;
|
File diff suppressed because it is too large
Load diff
|
@ -0,0 +1,839 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Battle functions and utility views
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Checks if a battle needs to start at a given location
|
||||
--
|
||||
-- Parameters:
|
||||
-- l_id Location to check
|
||||
--
|
||||
-- Returns:
|
||||
-- Whether or not a new battle is to be added
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.check_start( l_id INT )
|
||||
RETURNS BOOLEAN
|
||||
STRICT STABLE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
BEGIN
|
||||
PERFORM p.name_id
|
||||
FROM verse.planets p
|
||||
INNER JOIN fleets.fleets f ON f.location_id = p.name_id AND f.attacking
|
||||
LEFT OUTER JOIN fleets.movements m
|
||||
ON m.fleet_id = f.id
|
||||
LEFT OUTER JOIN battles.battles b
|
||||
ON b.location_id = p.name_id AND last_tick IS NULL
|
||||
WHERE p.name_id = l_id AND m.fleet_id IS NULL and b.id IS NULL;
|
||||
RETURN FOUND;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
--
|
||||
-- Creates or returns an empire's battle record
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
--
|
||||
-- Returns:
|
||||
-- the empire battle record's identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.goc_empire( e_id INT )
|
||||
RETURNS BIGINT
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
r_id BIGINT;
|
||||
BEGIN
|
||||
LOOP
|
||||
SELECT INTO r_id id FROM battles.empires
|
||||
WHERE empire_id = e_id;
|
||||
EXIT WHEN FOUND;
|
||||
|
||||
INSERT INTO battles.empires ( name , empire_id )
|
||||
SELECT name , id FROM naming.empire_names
|
||||
WHERE id = e_id
|
||||
RETURNING id INTO r_id;
|
||||
|
||||
PERFORM * FROM battles.empires
|
||||
WHERE empire_id = e_id AND id <> r_id;
|
||||
EXIT WHEN NOT FOUND;
|
||||
|
||||
DELETE FROM battles.empires WHERE id = r_id;
|
||||
END LOOP;
|
||||
RETURN r_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates or returns a protagonist's record
|
||||
--
|
||||
-- Parameters:
|
||||
-- b_id Battle identifier
|
||||
-- e_id Empire identifier
|
||||
-- mode Protagonist mode
|
||||
-- tick Current tick
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.goc_protagonist( b_id BIGINT , e_id INT , mode BOOLEAN , tick BIGINT )
|
||||
RETURNS BIGINT
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
be_id BIGINT;
|
||||
p_id BIGINT;
|
||||
lmode BOOLEAN;
|
||||
BEGIN
|
||||
be_id := battles.goc_empire( e_id );
|
||||
|
||||
LOOP
|
||||
SELECT INTO p_id id FROM battles.protagonists
|
||||
WHERE battle_id = b_id AND empire_id = be_id;
|
||||
EXIT WHEN FOUND;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO battles.protagonists ( battle_id , empire_id )
|
||||
VALUES ( b_id , be_id )
|
||||
RETURNING id INTO p_id;
|
||||
EXIT;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
SELECT INTO lmode attacking
|
||||
FROM battles.status_changes WHERE protagonist_id = p_id
|
||||
ORDER BY tick_identifier DESC LIMIT 1;
|
||||
IF NOT FOUND OR lmode <> mode
|
||||
THEN
|
||||
INSERT INTO battles.status_changes ( protagonist_id , tick_identifier , attacking )
|
||||
VALUES ( p_id , tick , mode );
|
||||
END IF;
|
||||
|
||||
RETURN p_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Initialises a battle record
|
||||
--
|
||||
-- Parameters:
|
||||
-- l_id Location
|
||||
-- tick The current tick's identifier
|
||||
--
|
||||
-- Returns:
|
||||
-- the battle's identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.initialise( l_id INT , tick BIGINT )
|
||||
RETURNS BIGINT
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
-- Battle ID
|
||||
b_id BIGINT;
|
||||
-- Battle planet ID
|
||||
bp_id BIGINT;
|
||||
-- Record for list operations
|
||||
rec RECORD;
|
||||
-- Protagonist ID
|
||||
prot_id BIGINT;
|
||||
-- Fleet status record ID
|
||||
bf_id BIGINT;
|
||||
-- Planet owner
|
||||
po_id INT;
|
||||
BEGIN
|
||||
-- Create main battle record
|
||||
INSERT INTO battles.battles ( location_id , first_tick )
|
||||
VALUES ( l_id , tick )
|
||||
RETURNING id INTO b_id;
|
||||
|
||||
-- Create planet record
|
||||
INSERT INTO battles.planets( battle_id , tick_identifier , change_type , name )
|
||||
SELECT b_id , tick , 'INIT'::battle_planet_change , n.name
|
||||
FROM naming.map_names n WHERE n.id = l_id
|
||||
RETURNING id INTO bp_id;
|
||||
|
||||
-- Insert list of initial buildings
|
||||
INSERT INTO battles.buildings ( planet_id , building_id , change )
|
||||
SELECT bp_id , b.building_id , b.amount
|
||||
FROM verse.planet_buildings b
|
||||
INNER JOIN tech.buildings bd ON bd.buildable_id = b.building_id
|
||||
WHERE b.planet_id = l_id AND bd.output_type = 'DEF' AND b.amount > 0;
|
||||
|
||||
-- Insert defensive power
|
||||
INSERT INTO battles.defences ( battle_id , tick_identifier , power )
|
||||
SELECT b_id , tick , floor( verse.adjust_production(
|
||||
verse.get_raw_production( p.name_id , 'DEF' ) , ph.current / p.population ) )
|
||||
FROM verse.planets p
|
||||
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
|
||||
WHERE p.name_id = l_id;
|
||||
|
||||
-- Add protagonists and initial status
|
||||
SELECT INTO po_id empire_id FROM emp.planets ep WHERE ep.planet_id = l_id;
|
||||
FOR rec IN SELECT f.owner_id AS id , f.attacking AS mode
|
||||
FROM fleets.fleets f
|
||||
INNER JOIN naming.empire_names n ON n.id = f.owner_id
|
||||
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
|
||||
WHERE f.location_id = l_id AND m.fleet_id IS NULL
|
||||
UNION SELECT ep.empire_id AS id , FALSE AS mode
|
||||
FROM emp.planets ep
|
||||
WHERE ep.planet_id = l_id
|
||||
LOOP
|
||||
prot_id := battles.goc_protagonist( b_id , rec.id , rec.mode , tick );
|
||||
IF po_id = rec.id THEN
|
||||
INSERT INTO battles.planet_ownership ( protagonist_id )
|
||||
VALUES ( prot_id );
|
||||
END IF;
|
||||
|
||||
-- Insert fleets
|
||||
INSERT INTO battles.fleets ( protagonist_id , tick_identifier , change_type )
|
||||
VALUES ( prot_id , tick , 'INIT'::battle_fleet_change )
|
||||
RETURNING id INTO bf_id;
|
||||
INSERT INTO battles.ships ( fleet_id , ship_id , change )
|
||||
SELECT bf_id , s.ship_id , sum( s.amount )
|
||||
FROM fleets.fleets f
|
||||
INNER JOIN fleets.ships s ON s.fleet_id = f.id
|
||||
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
|
||||
WHERE f.owner_id = rec.id AND f.location_id = l_id
|
||||
AND m.fleet_id IS NULL AND f.status <> 'DEPLOYING'
|
||||
GROUP BY s.ship_id;
|
||||
END LOOP;
|
||||
|
||||
RETURN b_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Adds fleet ship changes
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.add_fleet_change( f_id BIGINT , s_id INT , l_change INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
BEGIN
|
||||
LOOP
|
||||
UPDATE battles.ships SET change = change + l_change
|
||||
WHERE fleet_id = f_id AND ship_id = s_id;
|
||||
EXIT WHEN FOUND;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO battles.ships ( fleet_id , ship_id , change )
|
||||
VALUES ( f_id , s_id , l_change );
|
||||
EXIT;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Gets or create a planet's change record
|
||||
--
|
||||
-- Parameters:
|
||||
-- b_id Battle identifier
|
||||
-- ctype Change type
|
||||
-- tick Tick identifier
|
||||
--
|
||||
-- Returns:
|
||||
-- the planet's change record
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.goc_planet( b_id BIGINT , ctype battle_planet_change , tick BIGINT )
|
||||
RETURNS BIGINT
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
pr_id BIGINT;
|
||||
BEGIN
|
||||
LOOP
|
||||
SELECT INTO pr_id id FROM battles.planets
|
||||
WHERE battle_id = b_id AND change_type = ctype
|
||||
AND tick_identifier = tick;
|
||||
EXIT WHEN FOUND;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO battles.planets( battle_id , tick_identifier , change_type )
|
||||
VALUES ( b_id , tick , ctype )
|
||||
RETURNING id INTO pr_id;
|
||||
EXIT;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
RETURN pr_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Records building changes
|
||||
--
|
||||
-- Parameters:
|
||||
-- pcr_id Planet change record
|
||||
-- bt_id Building type
|
||||
-- amount Amount
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.record_building_change( pcr_id BIGINT , bt_id INT , amount INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
BEGIN
|
||||
LOOP
|
||||
UPDATE battles.buildings
|
||||
SET change = change + amount
|
||||
WHERE planet_id = pcr_id AND building_id = bt_id;
|
||||
EXIT WHEN FOUND;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO battles.buildings ( planet_id , building_id , change )
|
||||
VALUES ( pcr_id , bt_id , amount );
|
||||
EXIT;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Adds buildings to a planet's buildings list
|
||||
--
|
||||
-- Parameters:
|
||||
-- p_id Planet identifier
|
||||
-- bt_id Building type
|
||||
-- amount Amount of buildings to add
|
||||
-- tick Current tick identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.add_buildings( p_id INT , bt_id INT , amount INT , tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
b_id BIGINT;
|
||||
pcr_id BIGINT;
|
||||
BEGIN
|
||||
-- Check building type
|
||||
PERFORM buildable_id FROM tech.buildings WHERE buildable_id = bt_id AND output_type = 'DEF';
|
||||
IF NOT FOUND THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Get battle identifier
|
||||
SELECT INTO b_id id FROM battles.battles
|
||||
WHERE location_id = p_id AND last_tick IS NULL;
|
||||
IF NOT FOUND THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Record changes
|
||||
pcr_id := battles.goc_planet( b_id , 'BUILD' , tick );
|
||||
PERFORM battles.record_building_change( pcr_id , bt_id , amount );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Removes buildings to a planet's buildings list
|
||||
--
|
||||
-- Parameters:
|
||||
-- p_id Planet identifier
|
||||
-- bt_id Building type
|
||||
-- amount Amount of buildings to remove
|
||||
-- bdmg Whether the losses have been caused by battle damage
|
||||
-- tick Current tick identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.remove_buildings( p_id INT , bt_id INT , amount INT , bdmg BOOLEAN , tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
b_id BIGINT;
|
||||
pcr_id BIGINT;
|
||||
BEGIN
|
||||
-- Check building type
|
||||
PERFORM buildable_id FROM tech.buildings WHERE buildable_id = bt_id AND output_type = 'DEF';
|
||||
IF NOT FOUND THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Get battle identifier
|
||||
SELECT INTO b_id id FROM battles.battles
|
||||
WHERE location_id = p_id AND last_tick IS NULL;
|
||||
IF NOT FOUND THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Record changes
|
||||
pcr_id := battles.goc_planet( b_id , ( CASE WHEN bdmg THEN 'BATTLE' ELSE 'DESTROY' END )::battle_planet_change , tick );
|
||||
PERFORM battles.record_building_change( pcr_id , bt_id , -amount );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Adds a record when the planet is renamed
|
||||
--
|
||||
-- Parameters:
|
||||
-- p_id Planet identifier
|
||||
-- nnm New name
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.rename_planet( p_id INT , nnm TEXT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
b_id BIGINT;
|
||||
pcr_id BIGINT;
|
||||
BEGIN
|
||||
-- Get battle identifier
|
||||
SELECT INTO b_id id FROM battles.battles
|
||||
WHERE location_id = p_id AND last_tick IS NULL;
|
||||
IF NOT FOUND THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Record change
|
||||
pcr_id := battles.goc_planet( b_id , 'RENAME' , sys.get_tick() );
|
||||
UPDATE battles.planets
|
||||
SET name = nnm
|
||||
WHERE id = pcr_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Gets or creates a fleet change record
|
||||
--
|
||||
-- Parameters:
|
||||
-- bp_id Protagonist identifier
|
||||
-- tick Tick identifier
|
||||
-- ctype Change type
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.goc_fleet_change( bp_id BIGINT , tick BIGINT , ctype battle_fleet_change )
|
||||
RETURNS BIGINT
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
bf_id BIGINT;
|
||||
BEGIN
|
||||
LOOP
|
||||
SELECT INTO bf_id id FROM battles.fleets
|
||||
WHERE protagonist_id = bp_id AND tick_identifier = tick AND change_type = ctype;
|
||||
EXIT WHEN FOUND;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO battles.fleets ( protagonist_id , tick_identifier , change_type )
|
||||
VALUES ( bp_id , tick , ctype )
|
||||
RETURNING id INTO bf_id;
|
||||
EXIT;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
END LOOP;
|
||||
RETURN bf_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Adds a fleet to the battle
|
||||
--
|
||||
-- Parameters:
|
||||
-- b_id Battle identifier
|
||||
-- f_id Fleet identifier
|
||||
-- dep Whether the fleet was added at the end of its deployment phase
|
||||
-- tick Current tick
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.add_fleet( b_id BIGINT , f_id BIGINT , dep BOOLEAN , tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
e_id INT;
|
||||
f_att BOOLEAN;
|
||||
bp_id BIGINT;
|
||||
bf_id BIGINT;
|
||||
ctype battle_fleet_change;
|
||||
rec RECORD;
|
||||
BEGIN
|
||||
-- Get owner's protagonist record
|
||||
SELECT INTO e_id , f_att owner_id , attacking
|
||||
FROM fleets.fleets
|
||||
WHERE id = f_id;
|
||||
bp_id := battles.goc_protagonist( b_id , e_id , f_att , tick );
|
||||
|
||||
-- Try getting or creating the fleet's record
|
||||
ctype := ( CASE WHEN dep THEN 'BUILD' ELSE 'ARRIVE' END );
|
||||
bf_id := battles.goc_fleet_change( bp_id , tick , ctype );
|
||||
|
||||
-- Insert or update fleet ships
|
||||
FOR rec IN SELECT ship_id , amount FROM fleets.ships WHERE fleet_id = f_id
|
||||
LOOP
|
||||
PERFORM battles.add_fleet_change( bf_id , rec.ship_id , rec.amount );
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Removes a fleet from the battle
|
||||
--
|
||||
-- Parameters:
|
||||
-- b_id Battle identifier
|
||||
-- f_id Fleet identifier
|
||||
-- ctype Change type
|
||||
-- tick Current tick
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.remove_fleet( b_id BIGINT , f_id BIGINT , ctype battle_fleet_change , tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
e_id INT;
|
||||
f_att BOOLEAN;
|
||||
bp_id BIGINT;
|
||||
bf_id BIGINT;
|
||||
rec RECORD;
|
||||
BEGIN
|
||||
-- Get owner's protagonist record
|
||||
SELECT INTO e_id , f_att owner_id , attacking
|
||||
FROM fleets.fleets
|
||||
WHERE id = f_id;
|
||||
bp_id := battles.goc_protagonist( b_id , e_id , f_att , tick );
|
||||
|
||||
-- Try getting or creating the fleet's record
|
||||
bf_id := battles.goc_fleet_change( bp_id , tick , ctype );
|
||||
|
||||
-- Insert or update fleet ships
|
||||
FOR rec IN SELECT ship_id , amount FROM fleets.ships WHERE fleet_id = f_id
|
||||
LOOP
|
||||
PERFORM battles.add_fleet_change( bf_id , rec.ship_id , - rec.amount );
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Sets an empire's mode
|
||||
--
|
||||
-- Parameters:
|
||||
-- b_id Battle identifier
|
||||
-- e_id Empire identifier
|
||||
-- att Whether the empire is attacking or defending
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.set_mode( b_id BIGINT , e_id INT , att BOOLEAN )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
tick BIGINT;
|
||||
p_id BIGINT;
|
||||
BEGIN
|
||||
SELECT INTO p_id p.id
|
||||
FROM battles.empires e
|
||||
INNER JOIN battles.protagonists p ON p.empire_id = e.id
|
||||
WHERE e.empire_id = e_id AND p.battle_id = b_id;
|
||||
IF NOT FOUND THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
tick := sys.get_tick( );
|
||||
LOOP
|
||||
DELETE FROM battles.status_changes
|
||||
WHERE protagonist_id = p_id AND tick_identifier = tick AND attacking = ( NOT att );
|
||||
EXIT WHEN FOUND;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO battles.status_changes ( protagonist_id , tick_identifier , attacking )
|
||||
VALUES ( p_id , tick , att );
|
||||
EXIT;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
|
||||
PERFORM * FROM battles.status_changes
|
||||
WHERE protagonist_id = p_id AND tick_identifier = tick AND attacking = att;
|
||||
EXIT WHEN FOUND;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Inflicts damage to one side of the engagement
|
||||
--
|
||||
-- Parameters:
|
||||
-- b_id Battle identifer
|
||||
-- dmg Amount of damage to inflict
|
||||
-- att Whether damage is being inflicted to attacking fleets
|
||||
-- tick Current tick identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.inflict_damage( b_id BIGINT , dmg REAL , att BOOLEAN , tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
planet INT;
|
||||
tot_power BIGINT;
|
||||
st_power BIGINT;
|
||||
rec RECORD;
|
||||
BEGIN
|
||||
-- Get total power from fleets
|
||||
SELECT INTO tot_power sum( fs.power )
|
||||
FROM battles.battles b
|
||||
LEFT OUTER JOIN fleets.fleets f ON f.location_id = b.location_id AND f.attacking = att
|
||||
LEFT OUTER JOIN fleets.stats_view fs ON fs.id = f.id
|
||||
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
|
||||
WHERE b.id = b_id AND m.fleet_id IS NULL;
|
||||
IF tot_power IS NULL THEN
|
||||
tot_power := 0;
|
||||
END IF;
|
||||
SELECT INTO planet location_id FROM battles.battles WHERE id = b_id;
|
||||
|
||||
-- If damage is being inflicted to defence forces, handle defence buildings
|
||||
IF NOT att THEN
|
||||
st_power := battles.get_defence_power( b_id , tick );
|
||||
tot_power := tot_power + st_power;
|
||||
PERFORM sys.write_log( 'BattleUpdate' , 'TRACE'::log_level , 'About to inflict planet damage; total power: ' || tot_power
|
||||
|| '; planet power: ' || st_power || '; computed damage: ' || ( dmg * st_power / tot_power )::REAL );
|
||||
IF st_power <> 0 THEN
|
||||
PERFORM verse.inflict_battle_damage( planet , st_power , ( dmg * st_power / tot_power )::REAL , b_id , tick );
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- Inflict damage to fleets
|
||||
FOR rec IN SELECT f.id , fs.power
|
||||
FROM battles.battles b
|
||||
INNER JOIN fleets.fleets f ON f.location_id = b.location_id
|
||||
INNER JOIN fleets.stats_view fs ON fs.id = f.id
|
||||
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
|
||||
WHERE b.id = b_id AND m.fleet_id IS NULL AND f.attacking = att
|
||||
LOOP
|
||||
PERFORM fleets.inflict_battle_damage( rec.id , ( dmg * rec.power / tot_power )::REAL , b_id , tick );
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Computes the size/power of a planet's defences at a given tick
|
||||
--
|
||||
|
||||
CREATE TYPE planet_defence_size AS (
|
||||
item_id INT ,
|
||||
amount INT
|
||||
);
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.get_defence_size( b_id BIGINT , tick BIGINT )
|
||||
RETURNS SETOF planet_defence_size
|
||||
STRICT STABLE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
SELECT bb.building_id AS item_id , sum( bb.change )::INT AS amount
|
||||
FROM battles.planets bp
|
||||
INNER JOIN battles.buildings bb ON bb.planet_id = bp.id
|
||||
WHERE bp.battle_id = $1 AND bp.tick_identifier <= $2
|
||||
GROUP BY bb.building_id;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.set_defence_power( b_id BIGINT , tick BIGINT , pw BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
BEGIN
|
||||
IF battles.get_defence_power( b_id , tick ) <> pw
|
||||
THEN
|
||||
LOOP
|
||||
UPDATE battles.defences SET power = pw
|
||||
WHERE battle_id = b_id AND tick_identifier = tick;
|
||||
EXIT WHEN FOUND;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO battles.defences ( battle_id , tick_identifier , power )
|
||||
VALUES ( b_id , tick , pw );
|
||||
EXIT;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- EMPTY
|
||||
END;
|
||||
END LOOP;
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.get_defence_power( b_id BIGINT , tick BIGINT )
|
||||
RETURNS BIGINT
|
||||
STRICT STABLE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
SELECT power FROM battles.defences
|
||||
WHERE battle_id = $1 AND tick_identifier = (
|
||||
SELECT max( tick_identifier ) FROM battles.defences
|
||||
WHERE battle_id = $1 AND tick_identifier <= $2
|
||||
);
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Lists battle protagonists in a specific mode at a given tick
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.get_protagonists_with_mode( b_id BIGINT , tick BIGINT , mode BOOLEAN )
|
||||
RETURNS SETOF BIGINT
|
||||
STRICT STABLE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
SELECT protagonist_id
|
||||
FROM battles.status_changes c
|
||||
INNER JOIN (
|
||||
SELECT sc.protagonist_id , max( sc.tick_identifier ) AS tick_identifier
|
||||
FROM battles.status_changes sc
|
||||
INNER JOIN battles.protagonists p ON p.id = sc.protagonist_id
|
||||
WHERE sc.tick_identifier <= $2 AND p.battle_id = $1
|
||||
GROUP BY protagonist_id
|
||||
) x USING ( protagonist_id , tick_identifier )
|
||||
WHERE c.attacking = $3;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Computes the size/power of fleets in a specific mode at a given tick
|
||||
--
|
||||
|
||||
CREATE TYPE battle_fleet_size AS (
|
||||
protagonist_id BIGINT ,
|
||||
ship_id INT ,
|
||||
amount INT
|
||||
);
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.get_fleets_composition( b_id BIGINT , tick BIGINT )
|
||||
RETURNS SETOF battle_fleet_size
|
||||
STRICT STABLE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
SELECT bp.id AS protagonist_id , bs.ship_id AS item_id , sum( bs.change )::INT AS amount
|
||||
FROM battles.fleets bf
|
||||
INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
|
||||
INNER JOIN battles.ships bs ON bs.fleet_id = bf.id
|
||||
WHERE bp.battle_id = $1 AND bf.tick_identifier <= $2
|
||||
GROUP BY bp.id , bs.ship_id;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
CREATE TYPE battle_fleet_power AS (
|
||||
protagonist_id BIGINT ,
|
||||
power BIGINT
|
||||
);
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.get_fleets_power( b_id BIGINT , tick BIGINT )
|
||||
RETURNS SETOF battle_fleet_power
|
||||
STRICT STABLE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
SELECT ds.protagonist_id , ( CASE
|
||||
WHEN sum( ds.amount * s.power ) IS NULL THEN
|
||||
0
|
||||
ELSE
|
||||
sum( ds.amount * s.power )
|
||||
END ) AS power
|
||||
FROM battles.get_fleets_composition( $1 , $2 ) ds
|
||||
INNER JOIN tech.ships s ON s.buildable_id = ds.ship_id
|
||||
GROUP BY ds.protagonist_id;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.get_biggest_fleet_owner( b_id BIGINT , tick BIGINT )
|
||||
RETURNS INT
|
||||
STRICT STABLE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
SELECT e.empire_id
|
||||
FROM battles.get_fleets_power( $1 , $2 ) fp
|
||||
INNER JOIN battles.protagonists bp ON bp.id = fp.protagonist_id
|
||||
INNER JOIN battles.empires e ON e.id = bp.empire_id
|
||||
ORDER BY fp.power DESC
|
||||
LIMIT 1;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.get_fleets_power( b_id BIGINT , tick BIGINT , mode BOOLEAN )
|
||||
RETURNS BIGINT
|
||||
STRICT STABLE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
SELECT ( CASE
|
||||
WHEN sum( fp.power ) IS NULL THEN
|
||||
0
|
||||
ELSE
|
||||
sum( fp.power )
|
||||
END )::BIGINT
|
||||
FROM battles.get_fleets_power( $1 , $2 ) fp
|
||||
INNER JOIN battles.get_protagonists_with_mode( $1 , $2 , $3 ) pm
|
||||
ON fp.protagonist_id = pm;
|
||||
$$ LANGUAGE SQL;
|
|
@ -0,0 +1,483 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Views that are used to display battles
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Battle status view
|
||||
--
|
||||
|
||||
CREATE VIEW battles.current_status
|
||||
AS SELECT location_id AS location , id , ( battles.get_defence_power( id , sys.get_tick() ) + battles.get_fleets_power( id , sys.get_tick() , FALSE ) ) AS defence ,
|
||||
battles.get_fleets_power( id , sys.get_tick() , TRUE ) AS attack
|
||||
FROM battles.battles WHERE last_tick IS NULL;
|
||||
|
||||
GRANT SELECT ON battles.current_status TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Viewable battles, by empire
|
||||
--
|
||||
|
||||
CREATE VIEW battles.empire_list_view
|
||||
AS SELECT be.empire_id AS empire , b.id AS battle ,
|
||||
bpt.id AS protagonist ,
|
||||
b.first_tick , b.last_tick ,
|
||||
p.name_id AS planet ,
|
||||
s.x , s.y , p.orbit ,
|
||||
bpl.name
|
||||
FROM battles.empires be
|
||||
INNER JOIN battles.protagonists bpt ON bpt.empire_id = be.id
|
||||
INNER JOIN battles.battles b ON b.id = bpt.battle_id
|
||||
INNER JOIN verse.planets p ON p.name_id = b.location_id
|
||||
INNER JOIN verse.systems s ON s.id = p.system_id
|
||||
INNER JOIN battles.planets bpl ON bpl.battle_id = b.id AND bpl.change_type = 'INIT'
|
||||
WHERE be.empire_id IS NOT NULL;
|
||||
|
||||
GRANT SELECT ON battles.empire_list_view TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Ticks to include in a battle display
|
||||
--
|
||||
|
||||
CREATE VIEW battles.battle_ticks_view
|
||||
AS SELECT x.battle , x.tick FROM (
|
||||
SELECT battle_id AS battle , tick_identifier AS tick
|
||||
FROM battles.planets
|
||||
UNION SELECT battle_id AS battle , tick_identifier AS tick
|
||||
FROM battles.defences
|
||||
UNION SELECT bp.battle_id AS battle , bsc.tick_identifier AS tick
|
||||
FROM battles.status_changes bsc
|
||||
INNER JOIN battles.protagonists bp ON bp.id = bsc.protagonist_id
|
||||
UNION SELECT bp.battle_id AS battle , bf.tick_identifier AS tick
|
||||
FROM battles.fleets bf
|
||||
INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
|
||||
UNION SELECT id AS battle , last_tick AS tick
|
||||
FROM battles.battles
|
||||
WHERE last_tick IS NOT NULL
|
||||
) x
|
||||
ORDER BY x.tick;
|
||||
|
||||
GRANT SELECT ON battles.battle_ticks_view TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Mode history view
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.get_protagonist_status_at( bp_id BIGINT , tick_id BIGINT )
|
||||
RETURNS BOOLEAN
|
||||
STRICT IMMUTABLE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
SELECT attacking FROM battles.status_changes
|
||||
WHERE protagonist_id = $1 AND tick_identifier <= $2
|
||||
ORDER BY tick_identifier DESC LIMIT 1;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
CREATE VIEW battles.mode_history_view
|
||||
AS SELECT btv.battle , btv.tick , bp.id AS protagonist ,
|
||||
be.id AS empire_id , be.name AS empire_name ,
|
||||
battles.get_protagonist_status_at( bp.id , btv.tick ) AS attacking
|
||||
FROM battles.battle_ticks_view btv
|
||||
INNER JOIN battles.protagonists bp ON bp.battle_id = btv.battle
|
||||
INNER JOIN battles.empires be ON be.id = bp.empire_id
|
||||
ORDER BY btv.tick , be.name;
|
||||
|
||||
GRANT SELECT ON battles.mode_history_view TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Ships history
|
||||
--
|
||||
|
||||
CREATE VIEW battles.protagonist_ships
|
||||
AS SELECT DISTINCT bf.protagonist_id , bs.ship_id
|
||||
FROM battles.fleets bf
|
||||
INNER JOIN battles.ships bs ON bs.fleet_id = bf.id;
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.get_lost_ships( bp_id BIGINT , tick_id BIGINT, ship_id INT )
|
||||
RETURNS BIGINT
|
||||
STRICT IMMUTABLE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
SELECT -sum( fs.change )
|
||||
FROM battles.ships fs
|
||||
INNER JOIN battles.fleets bf ON fs.fleet_id = bf.id
|
||||
WHERE bf.protagonist_id = $1 AND bf.tick_identifier <= $2
|
||||
AND bf.change_type = 'BATTLE' AND fs.ship_id = $3
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.get_current_ships( bp_id BIGINT , tick_id BIGINT, ship_id INT )
|
||||
RETURNS BIGINT
|
||||
STRICT IMMUTABLE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
SELECT sum( fs.change )
|
||||
FROM battles.ships fs
|
||||
INNER JOIN battles.fleets bf ON fs.fleet_id = bf.id
|
||||
WHERE bf.protagonist_id = $1 AND bf.tick_identifier <= $2
|
||||
AND fs.ship_id = $3
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
CREATE VIEW battles.fleets_history
|
||||
AS SELECT elv.empire , elv.battle , btv.tick ,
|
||||
bpt.id AS protagonist , t.translated_string AS ship_type ,
|
||||
battles.get_current_ships( bpt.id , btv.tick , bps.ship_id ) AS current ,
|
||||
battles.get_lost_ships( bpt.id , btv.tick , bps.ship_id ) AS lost ,
|
||||
s.power AS ship_power
|
||||
FROM battles.empire_list_view elv
|
||||
INNER JOIN battles.battle_ticks_view btv USING (battle)
|
||||
INNER JOIN battles.protagonists bpt ON bpt.battle_id = elv.battle
|
||||
INNER JOIN battles.protagonist_ships bps ON bps.protagonist_id = bpt.id
|
||||
INNER JOIN tech.ships s ON s.buildable_id = bps.ship_id
|
||||
INNER JOIN naming.empire_names en ON en.id = elv.empire
|
||||
INNER JOIN users.credentials c ON c.address_id = en.owner_id
|
||||
INNER JOIN defs.translations t
|
||||
ON t.lang_id = c.language_id AND t.string_id = bps.ship_id
|
||||
ORDER BY s.power;
|
||||
|
||||
GRANT SELECT ON battles.fleets_history TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Protagonist presence in a battle at any given tick
|
||||
--
|
||||
|
||||
CREATE VIEW battles.protagonist_ship_types
|
||||
AS SELECT DISTINCT bp.id AS protagonist , bs.ship_id AS ship_type
|
||||
FROM battles.protagonists bp
|
||||
INNER JOIN battles.fleets bf ON bf.protagonist_id = bp.id
|
||||
INNER JOIN battles.ships bs ON bs.fleet_id = bf.id;
|
||||
|
||||
CREATE VIEW battles.ships_at_tick
|
||||
AS SELECT btv.battle , btv.tick , bp.id AS protagonist ,
|
||||
sum( battles.get_current_ships( bp.id , btv.tick, bs.ship_type ) ) AS ships
|
||||
FROM battles.battle_ticks_view btv
|
||||
INNER JOIN battles.protagonists bp ON bp.battle_id = btv.battle
|
||||
INNER JOIN battles.protagonist_ship_types bs ON bs.protagonist = bp.id
|
||||
GROUP BY btv.battle , btv.tick , bp.id;
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.get_current_ships( bp_id BIGINT , tick_id BIGINT )
|
||||
RETURNS BIGINT
|
||||
STRICT IMMUTABLE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
SELECT ( CASE WHEN sum( fs.change ) IS NULL THEN 0 ELSE sum( fs.change ) END )
|
||||
FROM battles.ships fs
|
||||
INNER JOIN battles.fleets bf ON fs.fleet_id = bf.id
|
||||
WHERE bf.protagonist_id = $1 AND bf.tick_identifier <= $2
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
CREATE VIEW battles.protagonist_presence
|
||||
AS SELECT btv.battle , btv.tick , bp.id AS protagonist ,
|
||||
( bpo.protagonist_id IS NOT NULL
|
||||
OR battles.get_current_ships( bp.id , btv.tick ) > 0 ) AS present ,
|
||||
( bpo.protagonist_id IS NOT NULL ) AS planet_owner
|
||||
FROM battles.battle_ticks_view btv
|
||||
INNER JOIN battles.protagonists bp ON bp.battle_id = btv.battle
|
||||
LEFT OUTER JOIN battles.planet_ownership bpo
|
||||
ON bpo.protagonist_id = bp.id AND ( bpo.abandoned_at IS NULL OR bpo.abandoned_at > btv.tick );
|
||||
|
||||
GRANT SELECT ON battles.protagonist_presence TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Buildings history
|
||||
--
|
||||
|
||||
|
||||
CREATE VIEW battles.buildings_list
|
||||
AS SELECT DISTINCT bp.battle_id AS battle , bb.building_id
|
||||
FROM battles.planets bp
|
||||
INNER JOIN battles.buildings bb ON bb.planet_id = bp.id;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.get_current_buildings( b_id BIGINT , tick_id BIGINT , building_id INT )
|
||||
RETURNS BIGINT
|
||||
STRICT IMMUTABLE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
SELECT sum( change )
|
||||
FROM battles.buildings b
|
||||
INNER JOIN battles.planets bp ON bp.id = b.planet_id
|
||||
WHERE bp.battle_id = $1 AND bp.tick_identifier <= $2 AND b.building_id = $3;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION battles.get_lost_buildings( b_id BIGINT , tick_id BIGINT , building_id INT )
|
||||
RETURNS BIGINT
|
||||
STRICT IMMUTABLE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
SELECT -sum( change )
|
||||
FROM battles.buildings b
|
||||
INNER JOIN battles.planets bp ON bp.id = b.planet_id
|
||||
WHERE bp.battle_id = $1 AND bp.tick_identifier <= $2
|
||||
AND b.building_id = $3 AND bp.change_type = 'BATTLE';
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
CREATE VIEW battles.raw_buildings_history
|
||||
AS SELECT btv.battle , btv.tick , bbl.building_id ,
|
||||
battles.get_current_buildings( btv.battle , btv.tick , bbl.building_id ) AS current ,
|
||||
battles.get_lost_buildings( btv.battle , btv.tick , bbl.building_id ) AS lost ,
|
||||
b.output AS raw_power
|
||||
FROM battles.battle_ticks_view btv
|
||||
INNER JOIN battles.buildings_list bbl USING (battle)
|
||||
INNER JOIN tech.buildings b ON b.buildable_id = bbl.building_id;
|
||||
|
||||
CREATE VIEW battles.raw_buildings_power
|
||||
AS SELECT rbh.battle , rbh.tick ,
|
||||
sum( rbh.current * rbh.raw_power ) AS raw_power ,
|
||||
battles.get_defence_power( rbh.battle , rbh.tick ) AS actual_power
|
||||
FROM battles.raw_buildings_history rbh
|
||||
GROUP BY rbh.battle , rbh.tick;
|
||||
|
||||
|
||||
CREATE VIEW battles.buildings_history
|
||||
AS SELECT elv.empire , rbh.battle , rbh.tick ,
|
||||
t.translated_string AS building ,
|
||||
( CASE WHEN rbh.current IS NULL THEN 0 ELSE rbh.current END ) AS current ,
|
||||
( CASE WHEN rbh.lost IS NULL THEN 0 ELSE rbh.lost END ) AS lost ,
|
||||
( CASE
|
||||
WHEN rbp.raw_power = 0 THEN
|
||||
rbh.raw_power
|
||||
ELSE
|
||||
rbh.raw_power::REAL * rbp.actual_power::REAL / rbp.raw_power::REAL
|
||||
END )::REAL AS power
|
||||
FROM battles.empire_list_view elv
|
||||
INNER JOIN battles.raw_buildings_history rbh USING (battle)
|
||||
INNER JOIN battles.raw_buildings_power rbp USING (battle,tick)
|
||||
INNER JOIN naming.empire_names en ON en.id = elv.empire
|
||||
INNER JOIN users.credentials c ON c.address_id = en.owner_id
|
||||
INNER JOIN defs.translations t
|
||||
ON t.string_id = rbh.building_id AND t.lang_id = c.language_id
|
||||
ORDER BY rbp.raw_power;
|
||||
|
||||
GRANT SELECT ON battles.buildings_history TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Events
|
||||
--
|
||||
|
||||
CREATE VIEW battles.rename_events
|
||||
AS SELECT bp.battle_id AS battle , bp.tick_identifier AS tick ,
|
||||
'RENAME'::TEXT AS event_type , TRUE AS is_planet ,
|
||||
NULL::BIGINT AS event_id , bp.name AS name , NULL::BOOLEAN AS attack
|
||||
FROM battles.planets bp
|
||||
WHERE bp.change_type = 'RENAME';
|
||||
|
||||
CREATE VIEW battles.switch_events
|
||||
AS SELECT bp.battle_id AS battle , bsc.tick_identifier AS tick ,
|
||||
'SWITCH'::TEXT AS event_type , FALSE AS is_planet ,
|
||||
NULL::BIGINT AS event_id , be.name AS name , bsc.attacking AS attack
|
||||
FROM battles.status_changes bsc
|
||||
INNER JOIN battles.protagonists bp ON bp.id = bsc.protagonist_id
|
||||
INNER JOIN battles.empires be ON be.id = bp.empire_id
|
||||
INNER JOIN battles.battles b
|
||||
ON b.id = bp.battle_id AND bsc.tick_identifier > b.first_tick;
|
||||
|
||||
CREATE VIEW battles.arrive_events
|
||||
AS SELECT bp.battle_id AS battle , bf.tick_identifier AS tick ,
|
||||
'ARRIVE'::TEXT AS event_type , FALSE AS is_planet ,
|
||||
bf.id AS event_id , be.name AS name ,
|
||||
battles.get_protagonist_status_at( bp.id , bf.tick_identifier ) AS attack
|
||||
FROM battles.fleets bf
|
||||
INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
|
||||
INNER JOIN battles.empires be ON be.id = bp.empire_id
|
||||
WHERE bf.change_type = 'ARRIVE';
|
||||
|
||||
CREATE VIEW battles.depart_events
|
||||
AS SELECT bp.battle_id AS battle , bf.tick_identifier AS tick ,
|
||||
'DEPART'::TEXT AS event_type , FALSE AS is_planet ,
|
||||
bf.id AS event_id , be.name AS name ,
|
||||
battles.get_protagonist_status_at( bp.id , bf.tick_identifier ) AS attack
|
||||
FROM battles.fleets bf
|
||||
INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
|
||||
INNER JOIN battles.empires be ON be.id = bp.empire_id
|
||||
WHERE bf.change_type = 'DEPART';
|
||||
|
||||
CREATE VIEW battles.fleet_destroy_events
|
||||
AS SELECT bp.battle_id AS battle , bf.tick_identifier AS tick ,
|
||||
'DESTROY'::TEXT AS event_type , FALSE AS is_planet ,
|
||||
bf.id AS event_id , be.name AS name ,
|
||||
battles.get_protagonist_status_at( bp.id , bf.tick_identifier ) AS attack
|
||||
FROM battles.fleets bf
|
||||
INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
|
||||
INNER JOIN battles.empires be ON be.id = bp.empire_id
|
||||
WHERE bf.change_type = 'DISBAND';
|
||||
|
||||
CREATE VIEW battles.fleet_build_events
|
||||
AS SELECT bp.battle_id AS battle , bf.tick_identifier AS tick ,
|
||||
'BUILD'::TEXT AS event_type , FALSE AS is_planet ,
|
||||
bf.id AS event_id , be.name AS name ,
|
||||
battles.get_protagonist_status_at( bp.id , bf.tick_identifier ) AS attack
|
||||
FROM battles.fleets bf
|
||||
INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
|
||||
INNER JOIN battles.empires be ON be.id = bp.empire_id
|
||||
WHERE bf.change_type = 'BUILD';
|
||||
|
||||
CREATE VIEW battles.bld_destroy_events
|
||||
AS SELECT bp.battle_id AS battle , bp.tick_identifier AS tick ,
|
||||
'DESTROY'::TEXT AS event_type , TRUE AS is_planet ,
|
||||
bp.id AS event_id , NULL::TEXT AS name , FALSE AS attack
|
||||
FROM battles.planets bp
|
||||
WHERE bp.change_type = 'DESTROY';
|
||||
|
||||
CREATE VIEW battles.bld_build_events
|
||||
AS SELECT bp.battle_id AS battle , bp.tick_identifier AS tick ,
|
||||
'BUILD'::TEXT AS event_type , TRUE AS is_planet ,
|
||||
bp.id AS event_id , NULL::TEXT AS name , FALSE AS attack
|
||||
FROM battles.planets bp
|
||||
WHERE bp.change_type = 'BUILD';
|
||||
|
||||
|
||||
CREATE VIEW battles.events_history
|
||||
AS SELECT x.* FROM (
|
||||
SELECT * FROM battles.rename_events
|
||||
UNION ALL SELECT * FROM battles.switch_events
|
||||
UNION ALL SELECT * FROM battles.arrive_events
|
||||
UNION ALL SELECT * FROM battles.depart_events
|
||||
UNION ALL SELECT * FROM battles.fleet_destroy_events
|
||||
UNION ALL SELECT * FROM battles.fleet_build_events
|
||||
UNION ALL SELECT * FROM battles.bld_destroy_events
|
||||
UNION ALL SELECT * FROM battles.bld_build_events
|
||||
) x
|
||||
ORDER BY x.tick DESC , x.is_planet DESC , x.event_type , x.attack , x.name;
|
||||
|
||||
GRANT SELECT ON battles.events_history TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Ships/buildings for events
|
||||
--
|
||||
|
||||
CREATE VIEW battles.planet_event_items
|
||||
AS SELECT elv.empire AS empire , TRUE AS is_planet , bp.id AS event_id ,
|
||||
bp.battle_id AS battle , bp.tick_identifier AS tick ,
|
||||
t.translated_string AS nature , abs( bb.change ) AS amount ,
|
||||
b.output AS power
|
||||
FROM battles.empire_list_view elv
|
||||
INNER JOIN battles.planets bp ON bp.battle_id = elv.battle
|
||||
INNER JOIN battles.buildings bb ON bb.planet_id = bp.id
|
||||
INNER JOIN naming.empire_names en ON en.id = elv.empire
|
||||
INNER JOIN users.credentials c ON c.address_id = en.owner_id
|
||||
INNER JOIN defs.translations t
|
||||
ON t.lang_id = c.language_id AND t.string_id = bb.building_id
|
||||
INNER JOIN tech.buildings b ON b.buildable_id = bb.building_id
|
||||
WHERE bp.change_type NOT IN ( 'INIT', 'BATTLE' );
|
||||
|
||||
CREATE VIEW battles.fleet_event_items
|
||||
AS SELECT elv.empire AS empire , FALSE AS is_planet , bf.id AS event_id ,
|
||||
bp.battle_id AS battle , bf.tick_identifier AS tick ,
|
||||
t.translated_string AS nature , abs( bs.change ) AS amount ,
|
||||
s.power AS power
|
||||
FROM battles.empire_list_view elv
|
||||
INNER JOIN battles.protagonists bp ON bp.battle_id = elv.battle
|
||||
INNER JOIN battles.fleets bf ON bf.protagonist_id = bp.id
|
||||
INNER JOIN battles.ships bs ON bs.fleet_id = bf.id
|
||||
INNER JOIN naming.empire_names en ON en.id = elv.empire
|
||||
INNER JOIN users.credentials c ON c.address_id = en.owner_id
|
||||
INNER JOIN defs.translations t
|
||||
ON t.lang_id = c.language_id AND t.string_id = bs.ship_id
|
||||
INNER JOIN tech.ships s ON s.buildable_id = bs.ship_id
|
||||
WHERE bf.change_type NOT IN ( 'INIT', 'BATTLE' );
|
||||
|
||||
CREATE VIEW battles.event_items
|
||||
AS SELECT x.* FROM (
|
||||
SELECT * FROM battles.planet_event_items
|
||||
UNION ALL SELECT * FROM battles.fleet_event_items
|
||||
) x
|
||||
ORDER BY x.power;
|
||||
|
||||
GRANT SELECT ON battles.event_items TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Battles list
|
||||
--
|
||||
|
||||
CREATE VIEW battles.last_presence
|
||||
AS SELECT protagonist , max( tick ) AS last_present
|
||||
FROM battles.protagonist_presence
|
||||
WHERE present
|
||||
GROUP BY protagonist;
|
||||
|
||||
CREATE VIEW battles.first_presence
|
||||
AS SELECT protagonist , min( tick ) AS first_present
|
||||
FROM battles.protagonist_presence
|
||||
WHERE present
|
||||
GROUP BY protagonist;
|
||||
|
||||
CREATE VIEW battles.last_update
|
||||
AS SELECT p.id AS protagonist , max( u.tick ) AS last_update
|
||||
FROM battles.protagonists p
|
||||
INNER JOIN battles.battle_ticks_view u ON u.battle = p.battle_id
|
||||
GROUP BY p.id;
|
||||
|
||||
CREATE VIEW battles.full_battles_list
|
||||
AS SELECT elv.empire , elv.battle , elv.planet , elv.x , elv.y , elv.orbit , elv.name ,
|
||||
fp.first_present AS first_tick , ( CASE
|
||||
WHEN elv.last_tick IS NOT NULL THEN
|
||||
lp.last_present
|
||||
WHEN lp.last_present = lu.last_update THEN
|
||||
NULL
|
||||
ELSE
|
||||
lp.last_present
|
||||
END )::BIGINT AS last_tick , lu.last_update ,
|
||||
( elv.last_tick IS NOT NULL ) AS finished
|
||||
FROM battles.empire_list_view elv
|
||||
INNER JOIN battles.first_presence fp USING (protagonist)
|
||||
INNER JOIN battles.last_presence lp USING (protagonist)
|
||||
INNER JOIN battles.last_update lu USING (protagonist);
|
||||
|
||||
CREATE TABLE battles.finished_battles_list(
|
||||
empire INT NOT NULL ,
|
||||
battle BIGINT NOT NULL ,
|
||||
planet INT NOT NULL ,
|
||||
x INT NOT NULL ,
|
||||
y INT NOT NULL ,
|
||||
orbit INT NOT NULL ,
|
||||
name VARCHAR( 20 ) NOT NULL ,
|
||||
first_tick BIGINT ,
|
||||
last_tick BIGINT ,
|
||||
last_update BIGINT ,
|
||||
PRIMARY KEY( empire , battle )
|
||||
);
|
||||
|
||||
CREATE VIEW battles.current_battles_list
|
||||
AS SELECT elv.empire , elv.battle , elv.planet , elv.x , elv.y , elv.orbit , elv.name ,
|
||||
fp.first_present AS first_tick , ( CASE
|
||||
WHEN lp.last_present = lu.last_update THEN
|
||||
NULL
|
||||
ELSE
|
||||
lp.last_present
|
||||
END )::BIGINT AS last_tick , lu.last_update
|
||||
FROM battles.empire_list_view elv
|
||||
INNER JOIN battles.first_presence fp USING (protagonist)
|
||||
INNER JOIN battles.last_presence lp USING (protagonist)
|
||||
INNER JOIN battles.last_update lu USING (protagonist)
|
||||
WHERE elv.last_tick IS NULL;
|
||||
|
||||
|
||||
CREATE VIEW battles.battles_list
|
||||
AS SELECT fbl.* , TRUE AS finished FROM battles.finished_battles_list fbl
|
||||
UNION ALL SELECT cbl.* , FALSE AS finished FROM battles.current_battles_list cbl;
|
||||
|
||||
GRANT SELECT ON battles.battles_list TO :dbuser;
|
|
@ -0,0 +1,354 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Alliance views and management functions
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Alliances public information
|
||||
--
|
||||
|
||||
CREATE VIEW emp.alliances_public
|
||||
AS SELECT a.id AS id , a.tag AS tag , a.name AS name ,
|
||||
a.leader_id AS leader_id , n.name AS leader_name ,
|
||||
count( p.* ) AS planets
|
||||
FROM emp.alliances a
|
||||
INNER JOIN naming.empire_names n
|
||||
ON n.id = a.leader_id
|
||||
LEFT OUTER JOIN emp.alliance_members am
|
||||
ON am.alliance_id = a.id AND NOT am.is_pending
|
||||
LEFT OUTER JOIN emp.planets p
|
||||
ON p.empire_id = am.empire_id
|
||||
GROUP BY a.id , a.tag , a.name , a.leader_id , n.name;
|
||||
|
||||
GRANT SELECT ON emp.alliances_public TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Alliance members / pending requests
|
||||
--
|
||||
|
||||
CREATE VIEW emp.alliance_membership
|
||||
AS SELECT a.alliance_id AS alliance , a.empire_id AS id ,
|
||||
n.name AS name , a.is_pending AS pending
|
||||
FROM emp.alliance_members a
|
||||
INNER JOIN naming.empire_names n
|
||||
ON n.id = a.empire_id
|
||||
ORDER BY n.name;
|
||||
|
||||
GRANT SELECT ON emp.alliance_membership TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Alliance planets
|
||||
--
|
||||
|
||||
CREATE VIEW emp.alliance_planets
|
||||
AS SELECT a.alliance_id AS alliance ,
|
||||
a.empire_id AS owner_id , en.name AS owner_name ,
|
||||
s.x AS x , s.y AS y , p.orbit AS orbit ,
|
||||
ep.planet_id AS planet_id , pn.name AS planet_name ,
|
||||
( bcs IS NOT NULL ) AS battle , bcs.defence , bcs.attack
|
||||
FROM emp.alliance_members a
|
||||
INNER JOIN naming.empire_names en ON en.id = a.empire_id
|
||||
INNER JOIN emp.planets ep ON ep.empire_id = a.empire_id
|
||||
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
|
||||
INNER JOIN verse.systems s ON s.id = p.system_id
|
||||
INNER JOIN naming.map_names pn ON pn.id = ep.planet_id
|
||||
LEFT OUTER JOIN battles.current_status bcs ON bcs.location = p.name_id
|
||||
WHERE NOT a.is_pending
|
||||
ORDER BY en.name , s.x , s.y , p.orbit;
|
||||
|
||||
GRANT SELECT ON emp.alliance_planets TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Creates an alliance
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
-- a_tag Alliance tag
|
||||
-- a_name Alliance name
|
||||
--
|
||||
-- Returns:
|
||||
-- a_id Alliance identifier (NULL on failure)
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.create_alliance( e_id INT , a_tag TEXT , a_name TEXT , OUT a_id INT )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
BEGIN
|
||||
BEGIN
|
||||
INSERT INTO emp.alliances ( tag , name , leader_id )
|
||||
VALUES ( a_tag , a_name , e_id )
|
||||
RETURNING id INTO a_id;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
a_id := NULL;
|
||||
RETURN;
|
||||
END;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO emp.alliance_members ( alliance_id , empire_id , is_pending )
|
||||
VALUES ( a_id , e_id , FALSE );
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
DELETE FROM emp.alliances WHERE id = a_id;
|
||||
a_id := NULL;
|
||||
RETURN;
|
||||
END;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION emp.create_alliance( INT , TEXT , TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Requests to join an alliance
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
-- a_id Alliance identifier
|
||||
--
|
||||
-- Returns:
|
||||
-- success Whether the operation was successful or not
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.join_alliance( e_id INT , a_id INT , OUT success BOOLEAN )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
BEGIN
|
||||
INSERT INTO emp.alliance_members( empire_id , alliance_id )
|
||||
VALUES ( e_id , a_id );
|
||||
DELETE FROM emp.enemy_alliances
|
||||
WHERE empire_id = e_id AND alliance_id = a_id;
|
||||
PERFORM events.alliance_request_event( a_id , e_id );
|
||||
PERFORM msgs.deliver_internal( );
|
||||
success := TRUE;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
success := FALSE;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION emp.join_alliance( INT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Removes an empire's pending alliance membership
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.cancel_join( e_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DELETE FROM emp.alliance_members WHERE empire_id = $1 AND is_pending;
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION emp.cancel_join( INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Leave an alliance
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.leave_alliance( e_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
l_id INT;
|
||||
a_id INT;
|
||||
BEGIN
|
||||
SELECT INTO a_id , l_id a.id , a.leader_id
|
||||
FROM emp.alliance_members m
|
||||
INNER JOIN emp.alliances a ON a.id = m.alliance_id
|
||||
WHERE m.empire_id = e_id AND NOT m.is_pending
|
||||
FOR UPDATE;
|
||||
|
||||
IF FOUND THEN
|
||||
IF l_id = e_id THEN
|
||||
PERFORM events.alliance_disband_event( a_id );
|
||||
DELETE FROM emp.alliances WHERE id = a_id;
|
||||
ELSE
|
||||
DELETE FROM emp.alliance_members WHERE empire_id = e_id;
|
||||
PERFORM events.alliance_quit_event( a_id , e_id );
|
||||
END IF;
|
||||
PERFORM msgs.deliver_internal( );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION emp.leave_alliance( INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Transfer alliance leadership
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier of an alliance's leader
|
||||
-- to_id Empire identifier of the alliance member who is being made the new leader
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.transfer_leadership( e_id INT , to_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
a_id INT;
|
||||
BEGIN
|
||||
SELECT INTO a_id a.id
|
||||
FROM emp.alliance_members m
|
||||
INNER JOIN emp.alliances a ON a.id = m.alliance_id AND a.leader_id = e_id
|
||||
WHERE m.empire_id = to_id AND NOT m.is_pending
|
||||
FOR UPDATE;
|
||||
|
||||
IF FOUND THEN
|
||||
UPDATE emp.alliances SET leader_id = to_id WHERE id = a_id;
|
||||
PERFORM events.alliance_lchange_event( a_id , e_id );
|
||||
PERFORM msgs.deliver_internal( );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION emp.transfer_leadership( INT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Accept new members into an alliance
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
-- r_ids Requests to accept
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.accept_members( e_id INT , r_ids INT[] )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
a_id INT;
|
||||
re_id INT;
|
||||
BEGIN
|
||||
SELECT INTO a_id id FROM emp.alliances WHERE leader_id = e_id FOR UPDATE;
|
||||
IF NOT FOUND THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
FOR re_id IN SELECT m.empire_id FROM emp.alliance_members m
|
||||
INNER JOIN unnest( r_ids ) rid ON m.empire_id = rid
|
||||
WHERE m.is_pending
|
||||
LOOP
|
||||
PERFORM events.alliance_response_event( a_id , re_id , TRUE );
|
||||
END LOOP;
|
||||
PERFORM msgs.deliver_internal( );
|
||||
|
||||
UPDATE emp.alliance_members SET is_pending = FALSE
|
||||
WHERE alliance_id = a_id AND empire_id IN ( SELECT * FROM unnest( r_ids ) );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION emp.accept_members( INT , INT[] ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Reject membership requests
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
-- r_ids Requests to reject
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.reject_members( e_id INT , r_ids INT[] )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
a_id INT;
|
||||
re_id INT;
|
||||
BEGIN
|
||||
SELECT INTO a_id id FROM emp.alliances WHERE leader_id = e_id FOR UPDATE;
|
||||
IF NOT FOUND THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
FOR re_id IN SELECT m.empire_id FROM emp.alliance_members m
|
||||
INNER JOIN unnest( r_ids ) rid ON m.empire_id = rid
|
||||
WHERE m.is_pending
|
||||
LOOP
|
||||
PERFORM events.alliance_response_event( a_id , re_id , FALSE );
|
||||
END LOOP;
|
||||
PERFORM msgs.deliver_internal( );
|
||||
|
||||
DELETE FROM emp.alliance_members
|
||||
WHERE alliance_id = a_id AND is_pending
|
||||
AND empire_id IN ( SELECT * FROM unnest( r_ids ) );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION emp.reject_members( INT , INT[] ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Kick members from an alliance
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
-- kick_ids Requests to reject
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION emp.kick_members( e_id INT , kick_ids INT[] )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
a_id INT;
|
||||
k_id INT;
|
||||
BEGIN
|
||||
SELECT INTO a_id id FROM emp.alliances WHERE leader_id = e_id FOR UPDATE;
|
||||
IF NOT FOUND THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
FOR k_id IN SELECT m.empire_id FROM emp.alliance_members m
|
||||
INNER JOIN unnest( kick_ids ) rid ON m.empire_id = rid
|
||||
WHERE NOT m.is_pending
|
||||
LOOP
|
||||
PERFORM events.alliance_kick_event( a_id , k_id );
|
||||
END LOOP;
|
||||
PERFORM msgs.deliver_internal( );
|
||||
|
||||
DELETE FROM emp.alliance_members
|
||||
WHERE alliance_id = a_id AND NOT is_pending
|
||||
AND empire_id IN ( SELECT * FROM unnest( kick_ids ) )
|
||||
AND empire_id <> e_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION emp.kick_members( INT , INT[] ) TO :dbuser;
|
File diff suppressed because it is too large
Load diff
|
@ -0,0 +1,150 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Views for empires' planet lists
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
--
|
||||
-- Basic planet information
|
||||
--
|
||||
|
||||
CREATE VIEW emp.planets_list_basic
|
||||
AS SELECT e.name_id AS empire ,
|
||||
p.name_id AS id , n.name ,
|
||||
s.x , s.y , p.orbit ,
|
||||
p.population , ph.current / p.population::REAL AS happiness ,
|
||||
floor( pm.income )::BIGINT AS income ,
|
||||
floor( pm.upkeep )::BIGINT AS upkeep
|
||||
FROM emp.empires e
|
||||
INNER JOIN emp.planets ep ON ep.empire_id = e.name_id
|
||||
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
|
||||
INNER JOIN naming.map_names n ON n.id = p.name_id
|
||||
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
|
||||
INNER JOIN verse.planet_money pm ON pm.planet_id = p.name_id
|
||||
INNER JOIN verse.systems s ON s.id = p.system_id;
|
||||
|
||||
|
||||
--
|
||||
-- Production
|
||||
--
|
||||
|
||||
CREATE VIEW emp.planets_list_prod
|
||||
AS SELECT id ,
|
||||
verse.adjust_production( verse.get_raw_production( id , 'WORK') , happiness ) AS military_production ,
|
||||
verse.adjust_production( verse.get_raw_production( id , 'CASH') , happiness ) AS industrial_production ,
|
||||
verse.adjust_production( verse.get_raw_production( id , 'POP') , happiness ) AS growth_production ,
|
||||
verse.adjust_production( verse.get_raw_production( id , 'DEF') , happiness ) AS static_defence
|
||||
FROM emp.planets_list_basic;
|
||||
|
||||
|
||||
--
|
||||
-- Civilian investment
|
||||
--
|
||||
|
||||
CREATE VIEW emp.planets_list_civ_invest
|
||||
AS SELECT q.planet_id AS id , sum( CASE WHEN qi.destroy THEN 0 ELSE qi.amount * qb.cost END ) - q.money AS civ_investment
|
||||
FROM verse.bld_queues q
|
||||
INNER JOIN verse.bld_items qi ON qi.queue_id = q.planet_id
|
||||
INNER JOIN tech.buildables qb ON qb.name_id = qi.building_id
|
||||
GROUP BY q.planet_id , q.money;
|
||||
|
||||
|
||||
--
|
||||
-- Military investment
|
||||
--
|
||||
|
||||
CREATE VIEW emp.planets_list_mil_invest
|
||||
AS SELECT q.planet_id AS id , sum( qi.amount * qb.cost ) - q.money AS mil_investment
|
||||
FROM verse.mil_queues q
|
||||
INNER JOIN verse.mil_items qi ON qi.queue_id = q.planet_id
|
||||
INNER JOIN tech.buildables qb ON qb.name_id = qi.ship_id
|
||||
GROUP BY q.planet_id , q.money;
|
||||
|
||||
|
||||
--
|
||||
-- First item on civilian queues
|
||||
--
|
||||
|
||||
CREATE VIEW emp.planets_list_civ_top
|
||||
AS SELECT qi.queue_id AS id , qi.amount AS civ_amount , qi.destroy AS civ_destroy , t.translated_string AS civ_name
|
||||
FROM verse.bld_items qi
|
||||
INNER JOIN emp.planets ep ON ep.planet_id = qi.queue_id
|
||||
INNER JOIN naming.empire_names en ON en.id = ep.empire_id
|
||||
INNER JOIN users.credentials cred ON cred.address_id = en.owner_id
|
||||
INNER JOIN defs.translations t ON t.lang_id = cred.language_id AND t.string_id = qi.building_id
|
||||
WHERE qi.queue_order = 0;
|
||||
|
||||
|
||||
--
|
||||
-- First item on military queues
|
||||
--
|
||||
|
||||
CREATE VIEW emp.planets_list_mil_top
|
||||
AS SELECT qi.queue_id AS id , qi.amount AS mil_amount , t.translated_string AS mil_name
|
||||
FROM verse.mil_items qi
|
||||
INNER JOIN emp.planets ep ON ep.planet_id = qi.queue_id
|
||||
INNER JOIN naming.empire_names en ON en.id = ep.empire_id
|
||||
INNER JOIN users.credentials cred ON cred.address_id = en.owner_id
|
||||
INNER JOIN defs.translations t ON t.lang_id = cred.language_id AND t.string_id = qi.ship_id
|
||||
WHERE qi.queue_order = 0;
|
||||
|
||||
|
||||
--
|
||||
-- Fleets
|
||||
--
|
||||
|
||||
CREATE VIEW emp.planets_list_fleets
|
||||
AS SELECT f.location_id AS id , ( CASE
|
||||
WHEN f.owner_id = ep.empire_id THEN 0
|
||||
WHEN f.attacking THEN 2
|
||||
ELSE 1
|
||||
END ) AS rel_type , sum( fs.power )::BIGINT AS power
|
||||
FROM fleets.fleets f
|
||||
INNER JOIN emp.planets ep ON f.location_id = ep.planet_id
|
||||
INNER JOIN fleets.stats_view fs ON fs.id = f.id
|
||||
LEFT OUTER JOIN fleets.movements fm ON fm.fleet_id = f.id
|
||||
WHERE fm IS NULL
|
||||
GROUP BY f.location_id , ( CASE
|
||||
WHEN f.owner_id = ep.empire_id THEN 0
|
||||
WHEN f.attacking THEN 2
|
||||
ELSE 1
|
||||
END );
|
||||
|
||||
|
||||
--
|
||||
-- Actual planet list
|
||||
--
|
||||
|
||||
CREATE VIEW emp.planets_list
|
||||
AS SELECT e.empire , e.id , e.name , e.x , e.y , e.orbit ,
|
||||
floor( e.population )::BIGINT AS population ,
|
||||
floor( 100 * e.happiness )::INT AS happiness ,
|
||||
e.income , e.upkeep ,
|
||||
floor( p.military_production )::BIGINT AS military_production ,
|
||||
floor( p.industrial_production )::BIGINT AS industrial_production ,
|
||||
floor( p.growth_production )::BIGINT AS growth_production ,
|
||||
( CASE WHEN ci IS NULL THEN 0 ELSE floor( ci.civ_investment ) END )::BIGINT AS civ_investment ,
|
||||
ct.civ_amount , ct.civ_destroy , ct.civ_name ,
|
||||
( CASE WHEN mi IS NULL THEN 0 ELSE floor( mi.mil_investment ) END )::BIGINT AS mil_investment ,
|
||||
mt.mil_amount , mt.mil_name ,
|
||||
floor( p.static_defence )::BIGINT AS static_defence ,
|
||||
( CASE WHEN of IS NULL THEN 0 ELSE of.power END ) AS own_fleet ,
|
||||
( CASE WHEN ff IS NULL THEN 0 ELSE ff.power END ) AS friendly_fleet ,
|
||||
( CASE WHEN hf IS NULL THEN 0 ELSE hf.power END ) AS hostile_fleet ,
|
||||
b.id AS battle
|
||||
FROM emp.planets_list_basic e
|
||||
INNER JOIN emp.planets_list_prod p USING ( id )
|
||||
LEFT OUTER JOIN emp.planets_list_civ_invest ci USING ( id )
|
||||
LEFT OUTER JOIN emp.planets_list_civ_top ct USING ( id )
|
||||
LEFT OUTER JOIN emp.planets_list_mil_invest mi USING ( id )
|
||||
LEFT OUTER JOIN emp.planets_list_mil_top mt USING ( id )
|
||||
LEFT OUTER JOIN emp.planets_list_fleets of ON of.id = e.id AND of.rel_type = 0
|
||||
LEFT OUTER JOIN emp.planets_list_fleets ff ON ff.id = e.id AND ff.rel_type = 1
|
||||
LEFT OUTER JOIN emp.planets_list_fleets hf ON hf.id = e.id AND hf.rel_type = 2
|
||||
LEFT OUTER JOIN battles.battles b ON b.location_id = e.id AND b.last_tick IS NULL
|
||||
ORDER BY e.x , e.y , e.orbit;
|
||||
|
||||
GRANT SELECT ON emp.planets_list TO :dbuser;
|
|
@ -0,0 +1,928 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Functions and views to create and manipulate events
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- EVENT CREATION FUNCTIONS --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
|
||||
--
|
||||
-- Creates a battle start event
|
||||
--
|
||||
-- Parameters:
|
||||
-- b_id Battle identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.battle_start_event( b_id BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
l_id INT;
|
||||
l_name TEXT;
|
||||
pe_id INT;
|
||||
c_tick BIGINT;
|
||||
evt_id BIGINT;
|
||||
BEGIN
|
||||
-- Get location name and identifier
|
||||
SELECT INTO l_id , l_name b.location_id , n.name
|
||||
FROM battles.battles b
|
||||
INNER JOIN naming.map_names n ON n.id = b.location_id
|
||||
WHERE b.id = b_id;
|
||||
|
||||
-- Create message for all protagonists
|
||||
c_tick := sys.get_tick( ) - 1;
|
||||
FOR pe_id IN SELECT be.empire_id
|
||||
FROM battles.battles b
|
||||
INNER JOIN battles.protagonists bp ON bp.battle_id = b.id
|
||||
INNER JOIN battles.empires be ON be.id = bp.empire_id
|
||||
WHERE b.id = b_id
|
||||
LOOP
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( pe_id , c_tick , 'PLANET' , 0 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.planet_events ( event_id , location_id , location_name , battle_id)
|
||||
VALUES ( evt_id , l_id , l_name , b_id );
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates a battle end event
|
||||
--
|
||||
-- Parameters:
|
||||
-- b_id Battle identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.battle_end_event( b_id BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
l_id INT;
|
||||
l_name TEXT;
|
||||
pe_id INT;
|
||||
c_tick BIGINT;
|
||||
evt_id BIGINT;
|
||||
BEGIN
|
||||
-- Get location name and identifier
|
||||
SELECT INTO l_id , l_name b.location_id , n.name
|
||||
FROM battles.battles b
|
||||
INNER JOIN naming.map_names n ON n.id = b.location_id
|
||||
WHERE b.id = b_id;
|
||||
|
||||
-- Create message for all protagonists
|
||||
c_tick := sys.get_tick( ) - 1;
|
||||
FOR pe_id IN SELECT empire FROM battles.battles_list
|
||||
WHERE battle = b_id AND last_update = last_tick
|
||||
LOOP
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( pe_id , c_tick , 'PLANET' , 1 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.planet_events ( event_id , location_id , location_name , battle_id)
|
||||
VALUES ( evt_id , l_id , l_name , b_id );
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates a strike start / end event
|
||||
--
|
||||
-- Parameters:
|
||||
-- p_id Planet identifier
|
||||
-- sevt Whether to create a strike start or a strike end event
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.strike_event( p_id INT , sevt BOOLEAN )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
p_name TEXT;
|
||||
po_id INT;
|
||||
c_tick BIGINT;
|
||||
evt_id BIGINT;
|
||||
BEGIN
|
||||
-- Get location name and owner identifier
|
||||
SELECT INTO p_name , po_id n.name , ep.empire_id
|
||||
FROM naming.map_names n
|
||||
INNER JOIN emp.planets ep ON ep.planet_id = n.id
|
||||
WHERE n.id = p_id;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Create message
|
||||
c_tick := sys.get_tick( ) - 1;
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( po_id , c_tick , 'PLANET' , ( CASE WHEN sevt THEN 2 ELSE 3 END ) , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.planet_events ( event_id , location_id , location_name )
|
||||
VALUES ( evt_id , p_id , p_name );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates events for a planet's ownership change
|
||||
--
|
||||
-- Parameters:
|
||||
-- p_id Planet identifier
|
||||
-- no_id New owner's identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.planet_ochange_events( p_id INT , no_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
p_name VARCHAR(20);
|
||||
no_name VARCHAR(20);
|
||||
oo_id INT;
|
||||
oo_name VARCHAR(20);
|
||||
evt_id BIGINT;
|
||||
c_tick BIGINT;
|
||||
BEGIN
|
||||
c_tick := sys.get_tick( ) - 1;
|
||||
|
||||
-- Get new owner's name and the planet's name
|
||||
SELECT INTO p_name name FROM naming.map_names WHERE id = p_id;
|
||||
SELECT INTO no_name name FROM naming.empire_names WHERE id = no_id;
|
||||
|
||||
-- Get previous owner's name and identifier
|
||||
SELECT INTO oo_id , oo_name ep.empire_id , n.name
|
||||
FROM emp.planets ep
|
||||
INNER JOIN naming.empire_names n ON n.id = ep.empire_id
|
||||
WHERE ep.planet_id = p_id;
|
||||
|
||||
-- If there is a previous owner, add planet loss event
|
||||
IF FOUND
|
||||
THEN
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( oo_id , c_tick , 'PLANET' , 4 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.planet_events ( event_id , location_id , location_name , empire_id , empire_name )
|
||||
VALUES ( evt_id , p_id , p_name , no_id , no_name );
|
||||
END IF;
|
||||
|
||||
-- Add planet taking event
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( no_id , c_tick , 'PLANET' , 6 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.planet_events ( event_id , location_id , location_name , empire_id , empire_name )
|
||||
VALUES ( evt_id , p_id , p_name , oo_id , oo_name );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates an event for planet abandon
|
||||
--
|
||||
-- Parameters:
|
||||
-- p_id Planet identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.planet_abandon_event( p_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
p_name VARCHAR(20);
|
||||
po_id INT;
|
||||
oo_name VARCHAR(20);
|
||||
evt_id BIGINT;
|
||||
BEGIN
|
||||
-- Get owner's ID and planet's name
|
||||
SELECT INTO p_name , po_id n.name , ep.empire_id
|
||||
FROM naming.map_names n
|
||||
INNER JOIN emp.planets ep ON ep.planet_id = n.id
|
||||
WHERE n.id = p_id;
|
||||
|
||||
-- Add abandon event
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( po_id , sys.get_tick( ) - 1 , 'PLANET' , 5 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.planet_events ( event_id , location_id , location_name )
|
||||
VALUES ( evt_id , p_id , p_name );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates an event for a technology's availability
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
-- t_id Technology identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.tech_ready_event( e_id INT , t_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
evt_id BIGINT;
|
||||
BEGIN
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( e_id , sys.get_tick( ) - 1 , 'EMPIRE' , 0 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.empire_events ( event_id , technology_id )
|
||||
VALUES ( evt_id , t_id );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates an event for start/end of debt
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
-- sevt Whether this is the start or the end
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.debt_event( e_id INT , sevt BOOLEAN )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( $1 , sys.get_tick( ) - 1 , 'EMPIRE' , ( CASE WHEN $2 THEN 1 ELSE 2 END ) , 'READY' );
|
||||
$$ LANGUAGE SQL;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates a "pending request" event
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Alliance identifier
|
||||
-- e_id Empire identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.alliance_request_event( a_id INT , e_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
a_tag TEXT;
|
||||
al_id INT;
|
||||
e_name TEXT;
|
||||
evt_id BIGINT;
|
||||
BEGIN
|
||||
-- Get the alliance's name and leader ID
|
||||
SELECT INTO a_tag , al_id tag , leader_id FROM emp.alliances WHERE id = a_id;
|
||||
|
||||
-- Get the joining player's name
|
||||
SELECT INTO e_name name FROM naming.empire_names WHERE id = e_id;
|
||||
|
||||
-- Create the event
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( al_id , sys.get_tick( ) , 'ALLIANCE' , 0 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag , empire_id , empire_name )
|
||||
VALUES ( evt_id , a_id , a_tag , e_id , e_name );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates a request validation/rejection event
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Alliance identifier
|
||||
-- e_id Empire identifier
|
||||
-- acc Whether the request was accepted or rejected
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.alliance_response_event( a_id INT , e_id INT , acc BOOLEAN )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
a_tag TEXT;
|
||||
e_name TEXT;
|
||||
evt_id BIGINT;
|
||||
BEGIN
|
||||
-- Get the alliance's name and leader ID
|
||||
SELECT INTO a_tag tag FROM emp.alliances WHERE id = a_id;
|
||||
|
||||
-- Get the requesting player's name
|
||||
SELECT INTO e_name name FROM naming.empire_names WHERE id = e_id;
|
||||
|
||||
-- Create the event
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( e_id , sys.get_tick( ) , 'ALLIANCE' , 1 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag , req_result )
|
||||
VALUES ( evt_id , a_id , a_tag , acc );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates a leadership change event
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Alliance identifier
|
||||
-- ol_id Previous leader's identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.alliance_lchange_event( a_id INT , ol_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
a_tag TEXT;
|
||||
al_id INT;
|
||||
al_name TEXT;
|
||||
am_id INT;
|
||||
evt_id BIGINT;
|
||||
BEGIN
|
||||
-- Get alliance tag, leader ID and leader name
|
||||
SELECT INTO a_tag , al_id , al_name a.tag , a.leader_id , n.name
|
||||
FROM emp.alliances a
|
||||
INNER JOIN naming.empire_names n ON n.id = a.leader_id
|
||||
WHERE a.id = a_id;
|
||||
|
||||
-- Notify both members and pending members
|
||||
FOR am_id IN SELECT empire_id FROM emp.alliance_members
|
||||
WHERE alliance_id = a_id AND empire_id <> ol_id
|
||||
LOOP
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( am_id , sys.get_tick( ) , 'ALLIANCE' , 2 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag , empire_id , empire_name )
|
||||
VALUES ( evt_id , a_id , a_tag , al_id , al_name );
|
||||
END LOOP;
|
||||
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates an alliance kick event
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Alliance identifier
|
||||
-- ol_id Member being kicked
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.alliance_kick_event( a_id INT , k_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
a_tag TEXT;
|
||||
al_id INT;
|
||||
k_name TEXT;
|
||||
am_id INT;
|
||||
evt_id BIGINT;
|
||||
BEGIN
|
||||
-- Get alliance tag and leader ID
|
||||
SELECT INTO a_tag , al_id a.tag , a.leader_id
|
||||
FROM emp.alliances a
|
||||
INNER JOIN naming.empire_names n ON n.id = a.leader_id
|
||||
WHERE a.id = a_id;
|
||||
SELECT INTO k_name name FROM naming.empire_names WHERE id = k_id;
|
||||
|
||||
-- Notify members
|
||||
FOR am_id IN SELECT empire_id FROM emp.alliance_members
|
||||
WHERE alliance_id = a_id AND empire_id <> al_id AND NOT is_pending
|
||||
LOOP
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( am_id , sys.get_tick( ) , 'ALLIANCE' , 3 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag , empire_id , empire_name )
|
||||
VALUES ( evt_id , a_id , a_tag , k_id , k_name );
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates an alliance quit event
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Alliance identifier
|
||||
-- q_id Member quitting the alliance
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.alliance_quit_event( a_id INT , q_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
a_tag TEXT;
|
||||
q_name TEXT;
|
||||
am_id INT;
|
||||
evt_id BIGINT;
|
||||
BEGIN
|
||||
-- Get alliance tag and quitter name
|
||||
SELECT INTO a_tag a.tag FROM emp.alliances a WHERE a.id = a_id;
|
||||
SELECT INTO q_name name FROM naming.empire_names WHERE id = q_id;
|
||||
|
||||
-- Notify members
|
||||
FOR am_id IN SELECT empire_id FROM emp.alliance_members
|
||||
WHERE alliance_id = a_id AND NOT is_pending
|
||||
LOOP
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( am_id , sys.get_tick( ) , 'ALLIANCE' , 4 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag , empire_id , empire_name )
|
||||
VALUES ( evt_id , a_id , a_tag , q_id , q_name );
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates an alliance disband event
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Alliance identifier
|
||||
-- q_id Member quitting the alliance
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.alliance_disband_event( a_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
a_tag TEXT;
|
||||
al_id INT;
|
||||
am_id INT;
|
||||
evt_id BIGINT;
|
||||
BEGIN
|
||||
-- Get alliance tag and quitter name
|
||||
SELECT INTO a_tag , al_id a.tag , leader_id FROM emp.alliances a WHERE a.id = a_id;
|
||||
|
||||
-- Notify members
|
||||
FOR am_id IN SELECT empire_id FROM emp.alliance_members
|
||||
WHERE alliance_id = a_id AND empire_id <> al_id
|
||||
LOOP
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( am_id , sys.get_tick( ) , 'ALLIANCE' , 5 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag )
|
||||
VALUES ( evt_id , a_id , a_tag );
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates empty build queue events or updates existing ones
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
-- p_id Planet identifier
|
||||
-- mqueue Whether the empty queue is the military or civilian queue
|
||||
-- c_tick Current tick
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.empty_queue_events( e_id INT , p_id INT , mqueue BOOLEAN , c_tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
evt_st INT;
|
||||
evt_id BIGINT;
|
||||
p_name TEXT;
|
||||
BEGIN
|
||||
evt_st := ( CASE WHEN mqueue THEN 1 ELSE 0 END );
|
||||
SELECT INTO evt_id event_id FROM events.events
|
||||
WHERE evt_type = 'QUEUE' AND evt_subtype = evt_st
|
||||
AND empire_id = e_id AND tick = c_tick;
|
||||
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( e_id , c_tick , 'QUEUE' , evt_st , 'TICK' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.queue_events VALUES ( evt_id );
|
||||
END IF;
|
||||
|
||||
SELECT INTO p_name name FROM naming.map_names WHERE id = p_id;
|
||||
INSERT INTO events.bqe_locations VALUES ( evt_id , p_id , p_name );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Commits fleet arrival events from the "fleet_arrivals" temporary table
|
||||
--
|
||||
-- Parameters:
|
||||
-- c_tick Current tick identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.commit_fleet_arrivals( c_tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
l_id INT;
|
||||
l_name TEXT;
|
||||
tg_id INT;
|
||||
tg_mode BOOLEAN;
|
||||
evt_id BIGINT;
|
||||
BEGIN
|
||||
FOR l_id , l_name , tg_id , tg_mode
|
||||
IN SELECT DISTINCT a.loc_id , a.loc_name , l.empire , l.attacking
|
||||
FROM fleet_arrivals a
|
||||
INNER JOIN fleets.locations_list_view l ON l.location = a.loc_id
|
||||
LOOP
|
||||
-- Create event record
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( tg_id , c_tick , 'FLEETS' , 0 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.fleets_events( event_id , location_id , location_name )
|
||||
VALUES ( evt_id , l_id , l_name );
|
||||
|
||||
-- List fleets
|
||||
INSERT INTO events.fleet_lists ( event_id , owner_id , owner_name , fleet_name , fleet_power , status , source_id , source_name )
|
||||
SELECT evt_id , a.own_id , a.own_name , a.name , a.power , ( CASE
|
||||
WHEN tg_id = a.own_id
|
||||
THEN tg_mode
|
||||
ELSE
|
||||
( tg_mode <> a.mode )
|
||||
END ) , a.src_id , a.src_name
|
||||
FROM fleet_arrivals a
|
||||
WHERE loc_id = l_id
|
||||
ORDER BY ( a.own_id = tg_id ) DESC , a.mode , own_name , name NULLS LAST;
|
||||
END LOOP;
|
||||
DROP TABLE fleet_arrivals;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Commits fleet departure events from the "fleet_departures" temporary table
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.commit_fleet_departures( )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
l_id INT;
|
||||
l_name TEXT;
|
||||
tg_id INT;
|
||||
tg_mode BOOLEAN;
|
||||
evt_id BIGINT;
|
||||
c_tick BIGINT;
|
||||
BEGIN
|
||||
c_tick := sys.get_tick( );
|
||||
FOR l_id , l_name , tg_id , tg_mode
|
||||
IN SELECT DISTINCT a.loc_id , a.loc_name , l.empire , l.attacking
|
||||
FROM fleet_departures a
|
||||
INNER JOIN fleets.locations_list_view l
|
||||
ON l.location = a.loc_id AND l.empire <> a.own_id
|
||||
LOOP
|
||||
-- Create event record
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( tg_id , c_tick , 'FLEETS' , 1 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.fleets_events( event_id , location_id , location_name )
|
||||
VALUES ( evt_id , l_id , l_name );
|
||||
|
||||
-- List fleets
|
||||
INSERT INTO events.fleet_lists ( event_id , owner_id , owner_name , fleet_name , fleet_power , status )
|
||||
SELECT evt_id , a.own_id , a.own_name , a.name , a.power , ( tg_mode <> a.mode )
|
||||
FROM fleet_departures a
|
||||
WHERE loc_id = l_id AND own_id <> tg_id
|
||||
ORDER BY a.mode , own_name , name NULLS LAST;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Commits fleet mode change events from the "fleet_switches" temporary table
|
||||
--
|
||||
-- Parameters:
|
||||
-- els Whether the switch was caused through the enemy list
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.commit_fleet_switches( els BOOLEAN )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
l_id INT;
|
||||
l_name TEXT;
|
||||
tg_id INT;
|
||||
tg_mode BOOLEAN;
|
||||
evt_id BIGINT;
|
||||
c_tick BIGINT;
|
||||
own_c BIGINT;
|
||||
other_c BIGINT;
|
||||
BEGIN
|
||||
c_tick := sys.get_tick( );
|
||||
FOR l_id , l_name , tg_id , tg_mode
|
||||
IN SELECT DISTINCT a.loc_id , a.loc_name , l.empire , l.attacking
|
||||
FROM fleet_switches a
|
||||
INNER JOIN fleets.locations_list_view l
|
||||
ON l.location = a.loc_id
|
||||
LOOP
|
||||
-- Handle other fleets
|
||||
SELECT INTO other_c count(*) FROM fleet_switches WHERE loc_id = l_id AND own_id <> tg_id;
|
||||
IF other_c > 0
|
||||
THEN
|
||||
-- Create event record
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( tg_id , c_tick , 'FLEETS' , 2 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.fleets_events( event_id , location_id , location_name )
|
||||
VALUES ( evt_id , l_id , l_name );
|
||||
|
||||
-- List fleets
|
||||
INSERT INTO events.fleet_lists ( event_id , owner_id , owner_name , fleet_name , fleet_power , status )
|
||||
SELECT evt_id , a.own_id , a.own_name , a.name , a.power , a.mode
|
||||
FROM fleet_switches a
|
||||
WHERE loc_id = l_id AND own_id <> tg_id
|
||||
ORDER BY a.mode , own_name , name NULLS LAST;
|
||||
END IF;
|
||||
|
||||
-- Handle own fleets
|
||||
CONTINUE WHEN NOT els;
|
||||
SELECT INTO own_c count(*) FROM fleet_switches WHERE loc_id = l_id AND own_id = tg_id;
|
||||
CONTINUE WHEN own_c = 0;
|
||||
|
||||
-- Create event record
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( tg_id , c_tick , 'FLEETS' , 3 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.fleets_events( event_id , location_id , location_name )
|
||||
VALUES ( evt_id , l_id , l_name );
|
||||
|
||||
-- List fleets
|
||||
INSERT INTO events.fleet_lists ( event_id , owner_id , owner_name , fleet_name , fleet_power , status )
|
||||
SELECT evt_id , a.own_id , a.own_name , a.name , a.power , a.mode
|
||||
FROM fleet_switches a
|
||||
WHERE loc_id = l_id AND own_id = tg_id
|
||||
ORDER BY a.mode , own_name , name NULLS LAST;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates a map name rejection event
|
||||
--
|
||||
-- Parameters:
|
||||
-- u_id Account identifier
|
||||
-- n_id Name identifier
|
||||
-- o_name Old name
|
||||
-- n_name New name
|
||||
-- w_sent Whether a warning was sent
|
||||
-- w_count Current warnings
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.map_name_rejected_event( u_id INT , n_id INT , o_name TEXT , n_name TEXT , w_sent BOOLEAN , w_count INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
e_id INT;
|
||||
evt_id BIGINT;
|
||||
BEGIN
|
||||
-- Get empire identifier
|
||||
SELECT INTO e_id e.name_id
|
||||
FROM emp.empires e
|
||||
INNER JOIN naming.empire_names en ON en.id = e.name_id
|
||||
WHERE en.owner_id = u_id;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Add event
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( e_id , sys.get_tick( ) - 1 , 'ADMIN' , 0 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.admin_events( event_id , n_warnings , location_id , old_name , new_name )
|
||||
VALUES( evt_id , ( CASE WHEN w_sent THEN w_count ELSE NULL END ) , n_id , o_name , n_name );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates an empire name rejection event
|
||||
--
|
||||
-- Parameters:
|
||||
-- n_id Name identifier
|
||||
-- o_name Old name
|
||||
-- n_name New name
|
||||
-- w_sent Whether a warning was sent
|
||||
-- w_count Current warnings
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.empire_name_rejected_event( n_id INT , o_name TEXT , n_name TEXT , w_sent BOOLEAN , w_count INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
evt_id BIGINT;
|
||||
BEGIN
|
||||
-- Add event
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( n_id , sys.get_tick( ) - 1 , 'ADMIN' , 1 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.admin_events( event_id , n_warnings ,old_name , new_name )
|
||||
VALUES( evt_id , ( CASE WHEN w_sent THEN w_count ELSE NULL END ) , o_name , n_name );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates an alliance name rejection event
|
||||
--
|
||||
-- Parameters:
|
||||
-- n_id Empire identifier
|
||||
-- o_name Alliance name
|
||||
-- w_sent Whether a warning was sent
|
||||
-- w_count Current warnings
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.alliance_name_rejected_event( n_id INT , o_name TEXT , w_sent BOOLEAN , w_count INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
evt_id BIGINT;
|
||||
BEGIN
|
||||
-- Add event
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( n_id , sys.get_tick( ) - 1 , 'ADMIN' , 2 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.admin_events( event_id , n_warnings , old_name )
|
||||
VALUES( evt_id , ( CASE WHEN w_sent THEN w_count ELSE NULL END ) , o_name );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates events for updated bug reports
|
||||
--
|
||||
-- Parameters:
|
||||
-- e_id Empire identifier
|
||||
-- br_id Bug report identifier
|
||||
-- s_id Submitter identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION events.bug_report_updated_event( e_id INT , br_id BIGINT , s_id BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
evt_id BIGINT;
|
||||
BEGIN
|
||||
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
|
||||
VALUES ( e_id , sys.get_tick( ) - 1 , 'BUGS' , 0 , 'READY' )
|
||||
RETURNING event_id INTO evt_id;
|
||||
INSERT INTO events.bug_events( event_id , bug_id , submitter_id )
|
||||
VALUES ( evt_id , br_id , s_id );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- EVENTS VIEWS, USED BY THE MESSAGE SYSTEM --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
|
||||
|
||||
--
|
||||
-- Main events lists
|
||||
--
|
||||
|
||||
CREATE VIEW events.queue_events_view
|
||||
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time , ed.*
|
||||
FROM events.events e
|
||||
INNER JOIN events.queue_events ed USING (event_id);
|
||||
|
||||
GRANT SELECT ON events.queue_events_view TO :dbuser;
|
||||
|
||||
|
||||
CREATE VIEW events.empire_events_view
|
||||
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time , s.name AS technology
|
||||
FROM events.events e
|
||||
LEFT OUTER JOIN events.empire_events ed USING (event_id)
|
||||
LEFT OUTER JOIN tech.levels tl ON tl.id = ed.technology_id
|
||||
LEFT OUTER JOIN defs.strings s ON s.id = tl.name_id
|
||||
WHERE e.evt_type = 'EMPIRE';
|
||||
|
||||
GRANT SELECT ON events.empire_events_view TO :dbuser;
|
||||
|
||||
|
||||
CREATE VIEW events.fleets_events_view
|
||||
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time ,
|
||||
ed.* , s.x , s.y , p.orbit
|
||||
FROM events.events e
|
||||
INNER JOIN events.fleets_events ed USING (event_id)
|
||||
INNER JOIN verse.planets p ON p.name_id = ed.location_id
|
||||
INNER JOIN verse.systems s ON s.id = p.system_id;
|
||||
|
||||
GRANT SELECT ON events.fleets_events_view TO :dbuser;
|
||||
|
||||
|
||||
CREATE VIEW events.planet_events_view
|
||||
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time ,
|
||||
ed.* , s.x , s.y , p.orbit
|
||||
FROM events.events e
|
||||
INNER JOIN events.planet_events ed USING (event_id)
|
||||
INNER JOIN verse.planets p ON p.name_id = ed.location_id
|
||||
INNER JOIN verse.systems s ON s.id = p.system_id;
|
||||
|
||||
GRANT SELECT ON events.planet_events_view TO :dbuser;
|
||||
|
||||
|
||||
CREATE VIEW events.alliance_events_view
|
||||
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time , ed.*
|
||||
FROM events.events e
|
||||
INNER JOIN events.alliance_events ed USING (event_id);
|
||||
|
||||
GRANT SELECT ON events.alliance_events_view TO :dbuser;
|
||||
|
||||
|
||||
CREATE VIEW events.admin_events_view
|
||||
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time , ed.*
|
||||
FROM events.events e
|
||||
INNER JOIN events.admin_events ed USING ( event_id );
|
||||
|
||||
GRANT SELECT ON events.admin_events_view TO :dbuser;
|
||||
|
||||
|
||||
CREATE VIEW events.bugs_events_view
|
||||
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time , ed.bug_id ,
|
||||
bs.is_admin AS submitter_admin , bs.name AS submitter_name
|
||||
FROM events.events e
|
||||
INNER JOIN events.bug_events ed USING ( event_id )
|
||||
INNER JOIN bugs.submitters bs USING ( submitter_id );
|
||||
|
||||
GRANT SELECT ON events.bugs_events_view TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Queue event locations
|
||||
--
|
||||
|
||||
CREATE VIEW events.queue_locations_view
|
||||
AS SELECT bqe.* , s.x , s.y , p.orbit
|
||||
FROM events.bqe_locations bqe
|
||||
INNER JOIN verse.planets p ON p.name_id = bqe.location_id
|
||||
INNER JOIN verse.systems s ON s.id = p.system_id;
|
||||
|
||||
GRANT SELECT ON events.queue_locations_view TO :dbuser;
|
File diff suppressed because it is too large
Load diff
|
@ -0,0 +1,937 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Functions and views to manage administrative accounts
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- ADMINISTRATOR MANAGEMENT FUNCTIONS --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
|
||||
|
||||
--
|
||||
-- Creates an administrative user
|
||||
--
|
||||
-- Parameters:
|
||||
-- u_addr User account address
|
||||
-- a_name Administrative name
|
||||
-- privs Administrative privileges
|
||||
--
|
||||
-- Returns:
|
||||
-- err_code Error code:
|
||||
-- 0 success
|
||||
-- 1 unknown user
|
||||
-- 2 invalid user status
|
||||
-- 3 name already in use
|
||||
-- 4 user already has admin access
|
||||
-- admin_id Administrator ID or NULL on failure
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.create_admin( IN u_addr TEXT , IN a_name TEXT , IN privs INT ,
|
||||
OUT err_code INT , OUT admin_id INT )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
u_id INT;
|
||||
u_stat TEXT;
|
||||
p_sha1 TEXT;
|
||||
p_md5 TEXT;
|
||||
BEGIN
|
||||
-- Get user ID, status and password hashes
|
||||
SELECT INTO u_id , u_stat , p_sha1 , p_md5 id , status , pass_sha1 , pass_md5
|
||||
FROM users.accounts_view
|
||||
WHERE address = lower( u_addr );
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
err_code := 1;
|
||||
RETURN;
|
||||
ELSEIF u_stat IN ( 'UNCONFIRMED' , 'BANNED' )
|
||||
THEN
|
||||
err_code := 2;
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Try adding the admin's record
|
||||
BEGIN
|
||||
INSERT INTO admin.administrators ( appear_as , pass_md5 , pass_sha1 , privileges )
|
||||
VALUES ( a_name , p_md5 , p_sha1 , privs )
|
||||
RETURNING id INTO admin_id;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
err_code := 3;
|
||||
RETURN;
|
||||
END;
|
||||
|
||||
-- Add the admin <-> user relation
|
||||
BEGIN
|
||||
INSERT INTO admin.admin_credentials ( administrator_id , credentials_id )
|
||||
VALUES ( admin_id , u_id );
|
||||
err_code := 0;
|
||||
PERFORM admin.write_log( admin_id , 'INFO'::log_level , 'Administrator ' || a_name || ' created' );
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
DELETE FROM admin.administrators WHERE id = admin_id;
|
||||
err_code := 4;
|
||||
admin_id := NULL;
|
||||
END;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION admin.create_admin( TEXT, TEXT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Type indicating the result of a connection attempt
|
||||
--
|
||||
|
||||
CREATE TYPE admin_connection_result
|
||||
AS ENUM( 'SUCCESS' , 'PASSWORD' , 'INACTIVE' );
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Log a connection attempt
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- c_res Connection attempt result
|
||||
-- addr IP address
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.log_connection( a_id INT , c_res admin_connection_result , addr TEXT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
BEGIN
|
||||
IF c_res = 'SUCCESS'
|
||||
THEN
|
||||
PERFORM admin.write_log( a_id , 'DEBUG'::log_level , 'Successful login attempt from ' || addr );
|
||||
ELSEIF c_res = 'PASSWORD'
|
||||
THEN
|
||||
PERFORM admin.write_log( a_id , 'WARNING'::log_level , 'Failed login attempt from ' || addr
|
||||
|| ' (incorrect password)' );
|
||||
ELSEIF c_res = 'INACTIVE'
|
||||
THEN
|
||||
PERFORM admin.write_log( a_id , 'WARNING'::log_level , 'Failed login attempt from ' || addr
|
||||
|| ' (inactive administrator)' );
|
||||
ELSE
|
||||
RAISE EXCEPTION 'Unknown connection attempt result value: %' , c_res;
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION admin.log_connection( INT , admin_connection_result , TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Log a disconnection
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.log_disconnection( a_id INT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
BEGIN
|
||||
PERFORM admin.write_log( a_id , 'DEBUG'::log_level , 'Administrator disconnected' );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION admin.log_disconnection( INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Modifies an administrator's password
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- p_sha1 SHA-1 hash of the new password
|
||||
-- p_md5 MD5 hash of the new password
|
||||
--
|
||||
-- Returns:
|
||||
-- success Whether the operation was successful
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.set_password( a_id INT , p_sha1 TEXT , p_md5 TEXT , OUT success BOOLEAN )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
u_sha1 TEXT;
|
||||
u_md5 TEXT;
|
||||
BEGIN
|
||||
SELECT INTO u_sha1 , u_md5 c.pass_sha1 , c.pass_md5
|
||||
FROM admin.admins_view a
|
||||
INNER JOIN users.credentials c ON c.address_id = a.account_id
|
||||
WHERE a.administrator_id = a_id AND a.active;
|
||||
success := ( FOUND AND u_sha1 <> p_sha1 AND u_md5 <> p_md5 );
|
||||
|
||||
IF success
|
||||
THEN
|
||||
UPDATE admin.administrators
|
||||
SET pass_sha1 = p_sha1 , pass_md5 = p_md5
|
||||
WHERE id = a_id;
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION admin.set_password( INT , TEXT , TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Resets an administrator's password to his/her player account password
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- su_id Superuser identifier
|
||||
--
|
||||
-- Returns:
|
||||
-- success Whether the operation was successful
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.reset_password( a_id INT , su_id INT , OUT success BOOLEAN )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
u_sha1 TEXT;
|
||||
u_md5 TEXT;
|
||||
a_name TEXT;
|
||||
BEGIN
|
||||
SELECT INTO u_sha1 , u_md5 , a_name c.pass_sha1 , c.pass_md5 , a.name
|
||||
FROM admin.admins_view a
|
||||
INNER JOIN users.credentials c ON c.address_id = a.account_id
|
||||
WHERE a.administrator_id = a_id AND a.active;
|
||||
success := FOUND;
|
||||
|
||||
IF success
|
||||
THEN
|
||||
UPDATE admin.administrators SET pass_sha1 = u_sha1 , pass_md5 = u_md5
|
||||
WHERE id = a_id;
|
||||
PERFORM admin.write_log( su_id , 'INFO'::log_level , 'Reset password of administrator ' || a_name );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION admin.reset_password( INT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Modifies an administrator's privileges
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- su_id Superuser identifier
|
||||
-- n_privs New privileges
|
||||
--
|
||||
-- Returns:
|
||||
-- success Whether the operation was successful
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.set_privileges( a_id INT , su_id INT , n_privs INT , OUT success BOOLEAN )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
a_name TEXT;
|
||||
o_privs INT;
|
||||
BEGIN
|
||||
SELECT INTO a_name , o_privs a.name , a.privileges
|
||||
FROM admin.admins_view a
|
||||
WHERE a.administrator_id = a_id AND a.address IS NOT NULL;
|
||||
success := FOUND;
|
||||
|
||||
IF success AND n_privs <> o_privs
|
||||
THEN
|
||||
UPDATE admin.administrators SET privileges = n_privs
|
||||
WHERE id = a_id;
|
||||
PERFORM admin.write_log( su_id , 'INFO'::log_level , 'Set privileges of administrator ' || a_name
|
||||
|| ' from ' || o_privs || ' to ' || n_privs );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION admin.set_privileges( INT , INT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- ADMINISTRATOR VIEWS --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
|
||||
|
||||
--
|
||||
-- Active administrators
|
||||
--
|
||||
|
||||
CREATE VIEW admin.admins_view
|
||||
AS SELECT adm.id AS administrator_id , adm.appear_as AS name , adm.privileges AS privileges ,
|
||||
adm.pass_sha1 , adm.pass_md5 , addr.id AS account_id , addr.address AS address ,
|
||||
( addr.id IS NOT NULL AND privileges <> 0 ) AS active ,
|
||||
( adm.pass_sha1 = cred.pass_sha1 AND adm.pass_md5 = cred.pass_md5 ) AS pass_change_required
|
||||
FROM admin.administrators adm
|
||||
LEFT OUTER JOIN admin.admin_credentials ac ON ac.administrator_id = adm.id
|
||||
LEFT OUTER JOIN users.credentials cred ON cred.address_id = ac.credentials_id
|
||||
LEFT OUTER JOIN users.addresses addr ON addr.id = ac.credentials_id;
|
||||
|
||||
GRANT SELECT ON admin.admins_view TO :dbuser;
|
||||
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- BANHAMMER FUNCTIONS --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
|
||||
|
||||
--
|
||||
-- Creates a ban request
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- u_id User identifier
|
||||
-- r_txt Reason for the ban request
|
||||
--
|
||||
-- Returns:
|
||||
-- Whether the operation was successful or not
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.add_ban_request( a_id INT , u_id INT , r_txt TEXT )
|
||||
RETURNS BOOLEAN
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
ban_id INT;
|
||||
BEGIN
|
||||
INSERT INTO admin.ban_requests ( requested_by , reason )
|
||||
VALUES ( a_id , r_txt )
|
||||
RETURNING id INTO ban_id;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO admin.active_ban_requests( request_id , credentials_id )
|
||||
VALUES( ban_id , u_id );
|
||||
RETURN TRUE;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
DELETE FROM admin.ban_requests WHERE id = ban_id;
|
||||
RETURN FALSE;
|
||||
END;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates a ban request using an email address as the source
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- u_addr Target user's address
|
||||
-- r_txt Reason for the ban request
|
||||
--
|
||||
-- Returns:
|
||||
-- err_code Error code:
|
||||
-- 0 success
|
||||
-- 1 user not found
|
||||
-- 2 duplicate request
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.request_ban_on_address( a_id INT , u_addr TEXT , r_txt TEXT , OUT err_code INT )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
u_id INT;
|
||||
BEGIN
|
||||
SELECT INTO u_id id FROM users.accounts_view
|
||||
WHERE address = u_addr;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
err_code := 1;
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
IF admin.add_ban_request( a_id , u_id , r_txt )
|
||||
THEN
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Requested ban of user #' || u_id || ' (address: ' || u_addr || ')' );
|
||||
err_code := 0;
|
||||
ELSE
|
||||
err_code := 2;
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION admin.request_ban_on_address( INT , TEXT, TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Creates a ban request using an empire name as the source
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- u_emp Target user's empire name
|
||||
-- r_txt Reason for the ban request
|
||||
--
|
||||
-- Returns:
|
||||
-- err_code Error code:
|
||||
-- 0 success
|
||||
-- 1 user not found
|
||||
-- 2 duplicate request
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.request_ban_on_empire( a_id INT , u_emp TEXT , r_txt TEXT , OUT err_code INT )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
u_id INT;
|
||||
BEGIN
|
||||
SELECT INTO u_id owner_id FROM naming.empire_names
|
||||
WHERE lower(name) = lower(u_emp);
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
err_code := 1;
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
IF admin.add_ban_request( a_id , u_id , r_txt )
|
||||
THEN
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Requested ban of user #' || u_id || ' (empire name: ' || u_emp || ')' );
|
||||
err_code := 0;
|
||||
ELSE
|
||||
err_code := 2;
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION admin.request_ban_on_empire( INT , TEXT, TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Rejects a ban request
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- b_id Ban request identifier
|
||||
-- r_txt Rejection reason
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.reject_ban_request( a_id INT , b_id INT , r_txt TEXT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
u_id INT;
|
||||
BEGIN
|
||||
-- Make sure the request exists and hasn't been validated
|
||||
SELECT INTO u_id credentials_id FROM admin.active_ban_requests
|
||||
WHERE request_id = b_id AND NOT validated
|
||||
FOR UPDATE;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
PERFORM * FROM admin.ban_requests WHERE id = b_id FOR UPDATE;
|
||||
|
||||
-- Insert archive entry
|
||||
INSERT INTO admin.archived_ban_requests( request_id , credentials_id )
|
||||
VALUES ( b_id , u_id );
|
||||
INSERT INTO admin.rejected_ban_requests( request_id , rejected_by , reason )
|
||||
VALUES ( b_id , a_id , r_txt );
|
||||
DELETE FROM admin.active_ban_requests WHERE request_id = b_id;
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Rejected ban of user #' || u_id );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION admin.reject_ban_request( INT , INT , TEXT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Confirms a ban request
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- b_id Ban request identifier
|
||||
--
|
||||
-- Returns:
|
||||
-- success Whether the operation was successful
|
||||
-- addr User's email address
|
||||
-- lang User's language
|
||||
-- r_txt Reason for the ban
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.confirm_ban_request( a_id INT , b_id INT , OUT success BOOLEAN , OUT addr TEXT , OUT lang TEXT , OUT r_txt TEXT )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
u_id INT;
|
||||
br_id INT;
|
||||
BEGIN
|
||||
-- Make sure there is an active, unvalidated ban request
|
||||
SELECT INTO u_id credentials_id FROM admin.active_ban_requests
|
||||
WHERE request_id = b_id AND NOT validated FOR UPDATE;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
success := FALSE;
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Make sure the request was created by another admin
|
||||
SELECT INTO br_id , r_txt requested_by , reason FROM admin.ban_requests
|
||||
WHERE id = b_id AND requested_by <> a_id
|
||||
FOR UPDATE;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
success := FALSE;
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Mark request as validated
|
||||
INSERT INTO admin.validated_ban_requests ( request_id , validated_by )
|
||||
VALUES ( b_id , a_id );
|
||||
UPDATE admin.active_ban_requests SET validated = TRUE
|
||||
WHERE request_id = b_id;
|
||||
|
||||
-- Update account
|
||||
PERFORM * FROM users.credentials WHERE address_id = u_id FOR UPDATE;
|
||||
LOOP
|
||||
UPDATE users.inactive_accounts SET since = now( ) , status = 'PROCESSED'
|
||||
WHERE credentials_id = u_id;
|
||||
EXIT WHEN FOUND;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO users.inactive_accounts ( credentials_id , since , status )
|
||||
VALUES ( u_id , now() , 'PROCESSED' );
|
||||
EXIT;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
-- Insert ban entry
|
||||
INSERT INTO users.bans ( account_id , ban_id )
|
||||
VALUES( u_id , b_id );
|
||||
|
||||
-- Set ban reason
|
||||
LOOP
|
||||
UPDATE users.reasons SET reason = r_txt WHERE account_id = u_id;
|
||||
EXIT WHEN FOUND;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO users.reasons( account_id , reason )
|
||||
VALUES ( u_id , r_txt );
|
||||
EXIT;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
success := TRUE;
|
||||
SELECT INTO addr , lang a.address , l.language
|
||||
FROM users.credentials c
|
||||
INNER JOIN users.addresses a ON a.id = c.address_id
|
||||
INNER JOIN defs.languages l ON l.id = c.language_id
|
||||
WHERE c.address_id = u_id;
|
||||
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Confirmed ban request on user #' || u_id );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION admin.confirm_ban_request( INT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Lifts an existing ban
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- b_id Ban identifier
|
||||
--
|
||||
-- Returns:
|
||||
-- success Whether the operation was successful
|
||||
-- addr User's email address
|
||||
-- lang User's language
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.lift_ban( a_id INT , b_id INT , OUT success BOOLEAN , OUT addr TEXT , OUT lang TEXT )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
u_id INT;
|
||||
redeem BOOLEAN;
|
||||
BEGIN
|
||||
-- Find / lock the ban and user records
|
||||
SELECT INTO u_id , redeem ab.credentials_id , ( aa.credentials_id IS NOT NULL )
|
||||
FROM admin.active_ban_requests ab
|
||||
INNER JOIN admin.ban_requests br ON br.id = ab.request_id
|
||||
INNER JOIN users.credentials c ON c.address_id = ab.credentials_id
|
||||
LEFT OUTER JOIN users.active_accounts aa ON aa.credentials_id = c.address_id
|
||||
WHERE ab.request_id = b_id AND ab.validated
|
||||
FOR UPDATE OF ab , br , c;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
success := FALSE;
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Delete the ban and reason records, and redeem the account if possible
|
||||
DELETE FROM users.bans WHERE account_id = u_id;
|
||||
DELETE FROM users.reasons WHERE account_id = u_id;
|
||||
IF redeem
|
||||
THEN
|
||||
DELETE FROM users.inactive_accounts WHERE credentials_id = u_id;
|
||||
END IF;
|
||||
|
||||
-- Delete active and validated ban entries
|
||||
DELETE FROM admin.validated_ban_requests WHERE request_id = b_id;
|
||||
DELETE FROM admin.active_ban_requests WHERE request_id = b_id;
|
||||
|
||||
-- Insert archive records
|
||||
INSERT INTO admin.archived_ban_requests( request_id , credentials_id )
|
||||
VALUES ( b_id , u_id );
|
||||
INSERT INTO admin.rejected_ban_requests( request_id , rejected_by , reason )
|
||||
VALUES ( b_id , a_id , '(ban lifted)' );
|
||||
|
||||
success := TRUE;
|
||||
SELECT INTO addr , lang a.address , l.language
|
||||
FROM users.credentials c
|
||||
INNER JOIN users.addresses a ON a.id = c.address_id
|
||||
INNER JOIN defs.languages l ON l.id = c.language_id
|
||||
WHERE c.address_id = u_id;
|
||||
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Ban on user #' || u_id || ' has been lifted'
|
||||
|| (CASE WHEN redeem THEN ' (empire redeemed)' ELSE '' END) );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION admin.lift_ban( INT , INT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Causes ban requests to expire
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.expire_ban_requests( )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
b_id INT;
|
||||
u_id INT;
|
||||
BEGIN
|
||||
FOR b_id , u_id IN SELECT br.id , ab.credentials_id FROM admin.ban_requests br
|
||||
INNER JOIN admin.active_ban_requests ab
|
||||
ON ab.request_id = br.id AND NOT validated
|
||||
WHERE now() - br.requested >= ( floor( sys.get_constant( 'accounts.banExpiration') ) || 's' )::INTERVAL
|
||||
FOR UPDATE
|
||||
LOOP
|
||||
INSERT INTO admin.archived_ban_requests ( request_id , credentials_id )
|
||||
VALUES ( b_id , u_id );
|
||||
DELETE FROM admin.active_ban_requests WHERE request_id = b_id;
|
||||
PERFORM sys.write_log( 'Bans' , 'INFO'::log_level , 'Ban request #' || b_id
|
||||
|| ' (user account #' || u_id || ') expired' );
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION admin.expire_ban_requests( ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Checks for banned players who still have empires past the expiration delay
|
||||
-- and deletes the empires.
|
||||
--
|
||||
-- Returns:
|
||||
-- Whether an empire was deleted
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.delete_banned_empires( )
|
||||
RETURNS BOOLEAN
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
e_id INT;
|
||||
a_id INT;
|
||||
BEGIN
|
||||
SELECT INTO e_id , a_id e.name_id , c.address_id
|
||||
FROM emp.empires e
|
||||
INNER JOIN naming.empire_names en ON en.id = e.name_id
|
||||
INNER JOIN users.credentials c ON c.address_id = en.owner_id
|
||||
INNER JOIN users.active_accounts aa ON aa.credentials_id = c.address_id
|
||||
INNER JOIN users.inactive_accounts ia ON ia.credentials_id = c.address_id
|
||||
INNER JOIN users.bans b ON b.account_id = ia.credentials_id
|
||||
WHERE now() - ia.since >= ( floor( sys.get_constant( 'accounts.banDelay') ) || 's' )::INTERVAL
|
||||
FOR UPDATE LIMIT 1;
|
||||
IF NOT FOUND
|
||||
THEN
|
||||
RETURN FALSE;
|
||||
END IF;
|
||||
|
||||
-- Delete empire and active account record
|
||||
PERFORM emp.delete_empire( e_id );
|
||||
DELETE FROM users.active_accounts WHERE credentials_id = a_id;
|
||||
PERFORM sys.write_log( 'Bans' , 'INFO'::log_level , 'Deleted empire #' || e_id
|
||||
|| ' (user account #' || a_id || ')' );
|
||||
|
||||
RETURN TRUE;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION admin.delete_banned_empires( ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- VIEWS RELATED TO THE BANHAMMER --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
|
||||
|
||||
--
|
||||
-- Pending requests
|
||||
--
|
||||
|
||||
CREATE VIEW admin.pending_bans
|
||||
AS SELECT r.id , r.requested_by AS requested_by_id , a.appear_as AS requested_by_name ,
|
||||
r.reason , r.requested , ab.credentials_id AS account_id , ad.address AS account_mail
|
||||
FROM admin.ban_requests r
|
||||
INNER JOIN admin.active_ban_requests ab
|
||||
ON ab.request_id = r.id AND NOT ab.validated
|
||||
INNER JOIN admin.administrators a ON a.id = r.requested_by
|
||||
INNER JOIN users.addresses ad ON ad.id = ab.credentials_id;
|
||||
|
||||
GRANT SELECT ON admin.pending_bans TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Expired / rejected ban requests
|
||||
--
|
||||
|
||||
CREATE VIEW admin.cancelled_bans
|
||||
AS SELECT r.id , r.requested_by AS requested_by_id , a.appear_as AS requested_by_name ,
|
||||
r.reason , r.requested , ab.credentials_id AS account_id , ad.address AS account_mail ,
|
||||
ab.updated , ( rb.request_id IS NULL ) AS expired ,
|
||||
rb.rejected_by AS rejected_by_id , ra.appear_as AS rejected_by_name ,
|
||||
rb.reason AS rejection_reason
|
||||
FROM admin.ban_requests r
|
||||
INNER JOIN admin.administrators a ON a.id = r.requested_by
|
||||
INNER JOIN admin.archived_ban_requests ab ON ab.request_id = r.id
|
||||
INNER JOIN users.addresses ad ON ad.id = ab.credentials_id
|
||||
LEFT OUTER JOIN admin.rejected_ban_requests rb ON rb.request_id = r.id
|
||||
LEFT OUTER JOIN admin.administrators ra ON ra.id = rb.rejected_by;
|
||||
|
||||
GRANT SELECT ON admin.cancelled_bans TO :dbuser;
|
||||
|
||||
|
||||
--
|
||||
-- Active bans
|
||||
--
|
||||
|
||||
CREATE VIEW admin.active_bans
|
||||
AS SELECT r.id , r.requested_by AS requested_by_id , a.appear_as AS requested_by_name ,
|
||||
r.reason , r.requested , ab.credentials_id AS account_id , ad.address AS account_mail ,
|
||||
vr.validated AS updated , ( ua.credentials_id IS NOT NULL ) AS redeemable ,
|
||||
vr.validated_by AS validated_by_id , va.appear_as AS validated_by_name
|
||||
FROM admin.ban_requests r
|
||||
INNER JOIN admin.administrators a ON a.id = r.requested_by
|
||||
INNER JOIN admin.active_ban_requests ab ON ab.request_id = r.id AND validated
|
||||
INNER JOIN users.addresses ad ON ad.id = ab.credentials_id
|
||||
INNER JOIN admin.validated_ban_requests vr ON vr.request_id = r.id
|
||||
INNER JOIN admin.administrators va ON va.id = vr.validated_by
|
||||
LEFT OUTER JOIN users.active_accounts ua ON ua.credentials_id = ab.credentials_id;
|
||||
|
||||
GRANT SELECT ON admin.active_bans TO :dbuser;
|
||||
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- WARNING SYSTEM FUNCTIONS --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
|
||||
|
||||
--
|
||||
-- Adds a warning to a player's account, triggering an automatic ban request if necessary
|
||||
--
|
||||
-- Parameters:
|
||||
-- a_id Administrator identifier
|
||||
-- u_id Player identifier
|
||||
--
|
||||
-- Returns:
|
||||
-- given Whether a warning was issued or not
|
||||
-- c_count Current amount of warnings for this player
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.give_player_warning( a_id INT , u_id INT , OUT given BOOLEAN , OUT c_count INT )
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
last_rec TIMESTAMP WITHOUT TIME ZONE;
|
||||
BEGIN
|
||||
LOOP
|
||||
SELECT INTO c_count , last_rec warnings, last_received
|
||||
FROM admin.warnings WHERE credentials_id = u_id
|
||||
FOR UPDATE;
|
||||
IF FOUND
|
||||
THEN
|
||||
given := ( now() - last_rec >= ( floor(sys.get_constant('accounts.warnings.grace')) || 's' )::INTERVAL );
|
||||
IF given
|
||||
THEN
|
||||
c_count := c_count + 1;
|
||||
UPDATE admin.warnings SET last_received = now( ) , warnings = c_count
|
||||
WHERE credentials_id = u_id;
|
||||
END IF;
|
||||
EXIT;
|
||||
END IF;
|
||||
|
||||
BEGIN
|
||||
INSERT INTO admin.warnings ( credentials_id ) VALUES ( u_id );
|
||||
given := TRUE;
|
||||
c_count := 1;
|
||||
EXIT;
|
||||
EXCEPTION
|
||||
WHEN unique_violation THEN
|
||||
-- Do nothing
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
IF given
|
||||
THEN
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Warning given to user #' || u_id || ' ('
|
||||
|| c_count || ' warning(s) total)' );
|
||||
|
||||
IF c_count >= sys.get_constant( 'accounts.warnings.autoBan' )
|
||||
THEN
|
||||
IF admin.add_ban_request( a_id , u_id , 'Automatic ban after ' || c_count || ' warnings' )
|
||||
THEN
|
||||
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Added automatic ban for user ' || u_id );
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Causes old warnings to expire
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.expire_warnings( )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
e_time INTERVAL;
|
||||
g_time INTERVAL;
|
||||
BEGIN
|
||||
e_time := ( floor( sys.get_constant( 'accounts.warnings.expiration' )
|
||||
* sys.get_constant( 'accounts.warnings.expiration.units' ) )
|
||||
|| 's' ) :: INTERVAL;
|
||||
g_time := ( floor(sys.get_constant('accounts.warnings.grace')) || 's' )::INTERVAL;
|
||||
UPDATE admin.warnings SET last_received = now( ) - g_time , warnings = warnings - 1
|
||||
WHERE now() - last_received >= g_time AND warnings > 0;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION admin.expire_warnings( ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Finds out if it is time to send the administrative recap e-mails
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION admin.is_recap_time( OUT is_time TIMESTAMP WITHOUT TIME ZONE )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
BEGIN
|
||||
SELECT INTO is_time last_admin_recap FROM sys.status
|
||||
WHERE now() - last_admin_recap >= '12 hours'::INTERVAL
|
||||
FOR UPDATE;
|
||||
IF FOUND
|
||||
THEN
|
||||
UPDATE sys.status SET last_admin_recap = now( );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION admin.is_recap_time( ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- USERS VIEW --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
|
||||
|
||||
|
||||
CREATE VIEW admin.user_empires
|
||||
AS SELECT en.*
|
||||
FROM emp.empires e
|
||||
INNER JOIN naming.empire_names en ON e.name_id = en.id;
|
||||
|
||||
CREATE VIEW admin.users_list
|
||||
AS SELECT av.* , ue.id AS current_empire_id , ue.name AS current_empire ,
|
||||
a1.id AS ban_req_id , a1.appear_as AS ban_req_name ,
|
||||
a2.id AS ban_val_id , a2.appear_as AS ban_val_name ,
|
||||
( CASE WHEN w IS NULL THEN 0 ELSE w.warnings END ) AS warnings_count ,
|
||||
w.last_received AS warnings_last
|
||||
FROM users.accounts_view av
|
||||
LEFT OUTER JOIN admin.user_empires ue ON ue.owner_id = av.id
|
||||
LEFT OUTER JOIN admin.ban_requests br ON br.id = av.ban_request_id
|
||||
LEFT OUTER JOIN admin.validated_ban_requests vbr ON vbr.request_id = br.id
|
||||
LEFT OUTER JOIN admin.administrators a1 ON a1.id = br.requested_by
|
||||
LEFT OUTER JOIN admin.administrators a2 ON a2.id = vbr.validated_by
|
||||
LEFT OUTER JOIN admin.warnings w ON w.credentials_id = av.id
|
||||
ORDER BY av.address;
|
||||
|
||||
GRANT SELECT ON admin.users_list TO :dbuser;
|
File diff suppressed because it is too large
Load diff
|
@ -0,0 +1,64 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Views used to generate the administration overview
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
CREATE VIEW admin.ov_new_messages
|
||||
AS SELECT admin_id , count(*) AS new_messages
|
||||
FROM msgs.admin_delivery
|
||||
WHERE status = 'UNREAD'
|
||||
GROUP BY admin_id;
|
||||
|
||||
|
||||
CREATE VIEW admin.ov_pending_names
|
||||
AS SELECT count(*) AS pending_names
|
||||
FROM naming.changed_map_names
|
||||
LEFT OUTER JOIN naming.validated_map_names USING (name_id)
|
||||
WHERE validated_at IS NULL;
|
||||
|
||||
|
||||
CREATE VIEW admin.ov_pending_bans
|
||||
AS SELECT count(*) AS pending_bans
|
||||
FROM admin.active_ban_requests
|
||||
WHERE NOT validated;
|
||||
|
||||
|
||||
CREATE VIEW admin.ov_pending_bugs
|
||||
AS SELECT count(*) AS pending_bugs
|
||||
FROM bugs.br_main_view
|
||||
WHERE status = 'PENDING';
|
||||
|
||||
|
||||
CREATE VIEW admin.ov_open_bugs
|
||||
AS SELECT count(*) AS open_bugs
|
||||
FROM bugs.br_main_view
|
||||
WHERE status = 'OPEN';
|
||||
|
||||
|
||||
CREATE VIEW admin.ov_updated_bugs
|
||||
AS SELECT administrator_id , count(*) AS updated_bugs
|
||||
FROM bugs.br_admin_view
|
||||
WHERE updated
|
||||
GROUP BY administrator_id;
|
||||
|
||||
|
||||
CREATE VIEW admin.overview
|
||||
AS SELECT a.id AS admin_id ,
|
||||
( CASE WHEN nm IS NULL THEN 0 ELSE nm.new_messages END )::BIGINT AS new_messages ,
|
||||
pn.pending_names , pb.pending_bans , pbg.pending_bugs , ob.open_bugs ,
|
||||
( CASE WHEN ub IS NULL THEN 0 ELSE ub.updated_bugs END )::BIGINT AS updated_bugs
|
||||
FROM admin.administrators a
|
||||
LEFT OUTER JOIN admin.ov_new_messages nm ON nm.admin_id = a.id
|
||||
INNER JOIN admin.ov_pending_names pn ON TRUE
|
||||
INNER JOIN admin.ov_pending_bans pb ON TRUE
|
||||
INNER JOIN admin.ov_pending_bugs pbg ON TRUE
|
||||
INNER JOIN admin.ov_open_bugs ob ON TRUE
|
||||
LEFT OUTER JOIN admin.ov_updated_bugs ub ON ub.administrator_id = a.id
|
||||
WHERE a.privileges <> 0;
|
||||
|
||||
GRANT SELECT ON admin.overview TO :dbuser;
|
|
@ -0,0 +1,172 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Game updates - control functions
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Start a tick
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.start_tick( OUT tick_id BIGINT )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
n_tick BIGINT;
|
||||
c_tick BIGINT;
|
||||
BEGIN
|
||||
-- Get next / current tick
|
||||
SELECT INTO n_tick , c_tick next_tick , current_tick
|
||||
FROM sys.status
|
||||
WHERE maintenance_start IS NULL
|
||||
FOR UPDATE;
|
||||
IF NOT FOUND OR c_tick IS NOT NULL THEN
|
||||
tick_id := NULL;
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Prepare game updates
|
||||
UPDATE sys.updates SET last_tick = n_tick , status = 'FUTURE'
|
||||
WHERE last_tick < n_tick;
|
||||
|
||||
-- Update system status
|
||||
UPDATE sys.status SET current_tick = n_tick , next_tick = n_tick + 1;
|
||||
|
||||
tick_id := n_tick;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.start_tick( ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Marks a tick as completed
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.end_tick( IN tick_id BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
BEGIN
|
||||
UPDATE events.events SET status = 'READY'
|
||||
WHERE status = 'TICK' AND tick = tick_id;
|
||||
UPDATE sys.status SET current_tick = NULL;
|
||||
PERFORM msgs.deliver_internal( );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Check if a tick got "stuck"
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.check_stuck_tick( OUT tick_id BIGINT )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
c_tick BIGINT;
|
||||
u_count INT;
|
||||
BEGIN
|
||||
-- Get next / current tick
|
||||
SELECT INTO c_tick current_tick
|
||||
FROM sys.status
|
||||
WHERE maintenance_start IS NULL
|
||||
FOR UPDATE;
|
||||
IF NOT FOUND OR c_tick IS NULL THEN
|
||||
tick_id := NULL;
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Are there any updates left?
|
||||
SELECT INTO u_count count(*) FROM sys.updates
|
||||
WHERE status = 'FUTURE' AND last_tick = c_tick;
|
||||
IF u_count = 0 THEN
|
||||
PERFORM sys.end_tick( c_tick );
|
||||
tick_id := NULL;
|
||||
ELSE
|
||||
tick_id := c_tick;
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.check_stuck_tick( ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
--
|
||||
-- Process game updates
|
||||
--
|
||||
-- Parameters:
|
||||
-- c_tick Current tick
|
||||
--
|
||||
-- Returns:
|
||||
-- TRUE if the function must be called again, FALSE otherwise
|
||||
--
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.process_updates( IN c_tick BIGINT , OUT has_more BOOLEAN )
|
||||
STRICT VOLATILE
|
||||
SECURITY DEFINER
|
||||
AS $$
|
||||
DECLARE
|
||||
b_size INT;
|
||||
p_utype update_type;
|
||||
utype update_type;
|
||||
uid BIGINT;
|
||||
BEGIN
|
||||
b_size := sys.get_constant( 'game.batchSize' );
|
||||
p_utype := NULL;
|
||||
|
||||
-- Mark at most b_size entries as being updated
|
||||
FOR uid , utype IN SELECT id , gu_type FROM sys.updates
|
||||
WHERE last_tick = c_tick AND status = 'FUTURE'
|
||||
ORDER BY gu_type LIMIT b_size
|
||||
LOOP
|
||||
IF p_utype IS NULL THEN
|
||||
p_utype := utype;
|
||||
END IF;
|
||||
EXIT WHEN utype <> p_utype;
|
||||
UPDATE sys.updates SET status = 'PROCESSING' WHERE id = uid;
|
||||
END LOOP;
|
||||
|
||||
has_more := p_utype IS NOT NULL;
|
||||
IF has_more THEN
|
||||
-- Execute actual updates
|
||||
EXECUTE 'SELECT sys.process_' || lower( p_utype::TEXT ) || '_updates( $1 )'
|
||||
USING c_tick;
|
||||
UPDATE sys.updates SET status = 'PROCESSED'
|
||||
WHERE status = 'PROCESSING' AND last_tick = c_tick;
|
||||
ELSE
|
||||
-- If nothing was found, we're done
|
||||
PERFORM sys.end_tick( c_tick );
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
GRANT EXECUTE ON FUNCTION sys.process_updates( BIGINT ) TO :dbuser;
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
|
@ -0,0 +1,81 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Game updates - empire money
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.process_empire_money_updates( c_tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
c_cash REAL;
|
||||
c_debt REAL;
|
||||
BEGIN
|
||||
-- Lock empires for update
|
||||
PERFORM e.name_id FROM sys.updates su
|
||||
INNER JOIN emp.updates eu
|
||||
ON eu.update_id = su.id
|
||||
INNER JOIN emp.empires e
|
||||
ON eu.empire_id = e.name_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'EMPIRE_MONEY'
|
||||
FOR UPDATE OF e;
|
||||
|
||||
-- Select all money-related data from empires being updated
|
||||
FOR rec IN SELECT e.name_id AS id , e.cash AS cash , e.debt AS debt ,
|
||||
( pov.planet_income - pov.planet_upkeep ) AS p_money ,
|
||||
fov.fleet_upkeep AS f_money , ( v.status = 'PROCESSED' ) AS on_vacation
|
||||
FROM sys.updates su
|
||||
INNER JOIN emp.updates eu ON eu.update_id = su.id
|
||||
INNER JOIN emp.empires e ON eu.empire_id = e.name_id
|
||||
INNER JOIN emp.fleets_overview fov ON fov.empire = e.name_id
|
||||
INNER JOIN emp.planets_overview pov ON pov.empire = e.name_id
|
||||
INNER JOIN naming.empire_names en ON en.id = e.name_id
|
||||
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'EMPIRE_MONEY'
|
||||
LOOP
|
||||
-- Compute new cash reserve
|
||||
c_cash := 0;
|
||||
IF rec.p_money IS NOT NULL THEN
|
||||
c_cash := c_cash + rec.p_money;
|
||||
END IF;
|
||||
IF rec.f_money IS NOT NULL THEN
|
||||
c_cash := c_cash - rec.f_money;
|
||||
END IF;
|
||||
|
||||
-- Effects of vacation mode
|
||||
IF rec.on_vacation
|
||||
THEN
|
||||
c_cash := c_cash / sys.get_constant( 'vacation.cashDivider' );
|
||||
END IF;
|
||||
|
||||
-- Handle debt
|
||||
c_cash := rec.cash + c_cash / 1440.0;
|
||||
IF c_cash < 0 THEN
|
||||
c_debt := -c_cash;
|
||||
c_cash := 0;
|
||||
ELSE
|
||||
c_debt := 0;
|
||||
END IF;
|
||||
|
||||
IF rec.debt > 0 AND c_debt = 0
|
||||
THEN
|
||||
PERFORM events.debt_event( rec.id , FALSE );
|
||||
ELSEIF rec.debt = 0 AND c_debt > 0
|
||||
THEN
|
||||
PERFORM events.debt_event( rec.id , TRUE );
|
||||
END IF;
|
||||
|
||||
-- Update empire
|
||||
UPDATE emp.empires SET cash = c_cash , debt = c_debt
|
||||
WHERE name_id = rec.id;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
|
@ -0,0 +1,86 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Game updates - empire research
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.process_empire_research_updates( c_tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
r_points REAL;
|
||||
tu_rec RECORD;
|
||||
BEGIN
|
||||
-- Lock empires for update and planets for share
|
||||
PERFORM e.name_id FROM sys.updates su
|
||||
INNER JOIN emp.updates eu ON eu.update_id = su.id
|
||||
INNER JOIN emp.empires e ON eu.empire_id = e.name_id
|
||||
INNER JOIN emp.planets ep ON ep.empire_id = e.name_id
|
||||
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'EMPIRE_RESEARCH'
|
||||
FOR UPDATE OF e
|
||||
FOR SHARE OF ep , p;
|
||||
|
||||
-- Process empires
|
||||
FOR rec IN SELECT e.name_id AS id , ( v.status = 'PROCESSED' ) AS on_vacation ,
|
||||
sum( p.population ) AS population
|
||||
FROM sys.updates su
|
||||
INNER JOIN emp.updates eu ON eu.update_id = su.id
|
||||
INNER JOIN emp.empires e ON eu.empire_id = e.name_id
|
||||
INNER JOIN emp.planets ep ON ep.empire_id = e.name_id
|
||||
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
|
||||
INNER JOIN naming.empire_names en ON en.id = e.name_id
|
||||
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'EMPIRE_RESEARCH'
|
||||
GROUP BY e.name_id , v.status
|
||||
LOOP
|
||||
-- Insert any missing tech line
|
||||
INSERT INTO emp.technologies ( empire_id , line_id )
|
||||
SELECT rec.id , l.name_id
|
||||
FROM tech.lines l
|
||||
LEFT OUTER JOIN emp.technologies t
|
||||
ON t.line_id = l.name_id AND t.empire_id = rec.id
|
||||
WHERE t.empire_id IS NULL;
|
||||
|
||||
-- Compute research output
|
||||
r_points := rec.population * sys.get_constant( 'game.work.rpPerPopUnit' ) / 1440.0;
|
||||
IF rec.on_vacation
|
||||
THEN
|
||||
r_points := r_points / sys.get_constant( 'vacation.researchDivider' );
|
||||
END IF;
|
||||
|
||||
-- Update technologies where:
|
||||
-- 1) the level actually exists and
|
||||
-- 2) accumulated points haven't reach the level's
|
||||
FOR tu_rec IN SELECT t.line_id AS line_id , t.accumulated AS accumulated ,
|
||||
l.points AS points , ( l.points - t.accumulated ) AS diff ,
|
||||
l.id AS level_id
|
||||
FROM emp.technologies t
|
||||
INNER JOIN tech.levels l ON l.line_id = t.line_id
|
||||
AND l.level = t.level AND t.accumulated < l.points
|
||||
WHERE t.empire_id = rec.id
|
||||
FOR UPDATE OF t
|
||||
LOOP
|
||||
UPDATE emp.technologies t SET accumulated = ( CASE
|
||||
WHEN tu_rec.diff <= r_points THEN tu_rec.points
|
||||
ELSE tu_rec.accumulated + r_points
|
||||
END )
|
||||
WHERE t.line_id = tu_rec.line_id AND t.empire_id = rec.id;
|
||||
|
||||
-- Send message
|
||||
IF tu_rec.diff <= r_points
|
||||
THEN
|
||||
PERFORM events.tech_ready_event( rec.id , tu_rec.level_id );
|
||||
END IF;
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
|
@ -0,0 +1,62 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Game updates - damage fleets and buildings when an
|
||||
-- empire is out of cash and has too much upkeep
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.process_empire_debt_updates( c_tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
fleet_dr REAL;
|
||||
bld_dr REAL;
|
||||
empire INT;
|
||||
debt REAL;
|
||||
upkeep REAL;
|
||||
BEGIN
|
||||
fleet_dr := sys.get_constant( 'game.debt.fleet');
|
||||
bld_dr := sys.get_constant( 'game.debt.buildings');
|
||||
|
||||
FOR empire, debt IN SELECT e.name_id AS id , e.debt
|
||||
FROM sys.updates su
|
||||
INNER JOIN emp.updates eu ON eu.update_id = su.id
|
||||
INNER JOIN emp.empires e ON eu.empire_id = e.name_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'EMPIRE_DEBT' AND e.debt > 0
|
||||
FOR UPDATE
|
||||
LOOP
|
||||
PERFORM sys.write_log( 'EmpireDebt' , 'DEBUG'::log_level , 'Handling debt for empire #'
|
||||
|| empire || ' (at tick: ' || debt || '; daily: ' || ( debt * 1440 ) || ')' );
|
||||
debt := debt * 1440.0;
|
||||
|
||||
-- Does the empire own fleets?
|
||||
SELECT INTO upkeep sum( d.upkeep * s.amount )
|
||||
FROM fleets.fleets f
|
||||
INNER JOIN fleets.ships s ON s.fleet_id = f.id
|
||||
INNER JOIN tech.buildables d ON d.name_id = s.ship_id
|
||||
WHERE f.owner_id = empire;
|
||||
IF upkeep IS NOT NULL
|
||||
THEN
|
||||
PERFORM fleets.handle_debt( empire , upkeep , ( CASE WHEN debt > upkeep THEN upkeep ELSE debt END ) , fleet_dr );
|
||||
debt := debt - upkeep;
|
||||
CONTINUE WHEN debt <= 0;
|
||||
END IF;
|
||||
|
||||
-- Does the empire have buildings?
|
||||
SELECT INTO upkeep sum( d.upkeep * b.amount )
|
||||
FROM emp.planets ep
|
||||
INNER JOIN verse.planet_buildings b ON b.planet_id = ep.planet_id
|
||||
INNER JOIN tech.buildables d ON d.name_id = b.building_id
|
||||
WHERE ep.empire_id = empire;
|
||||
CONTINUE WHEN NOT FOUND OR upkeep = 0;
|
||||
PERFORM verse.handle_debt( empire , upkeep , debt , bld_dr );
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
|
@ -0,0 +1,148 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Game updates - fleet arrivals
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.process_planet_fleet_arrivals_updates( c_tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
lstat BOOLEAN;
|
||||
f_ids BIGINT[];
|
||||
BEGIN
|
||||
-- Lock all records
|
||||
PERFORM f.id FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
|
||||
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
|
||||
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
|
||||
INNER JOIN emp.empires e ON e.name_id = f.owner_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_FLEET_ARRIVALS'
|
||||
AND f.status = 'AVAILABLE' AND fm.time_left = 1
|
||||
FOR UPDATE;
|
||||
|
||||
-- Update attack status according to planet owners and enemy lists
|
||||
FOR rec IN SELECT ep.empire_id AS planet_owner , p.name_id AS planet ,
|
||||
f.owner_id AS fleet_owner , ( v.status = 'PROCESSED' AND b.id IS NULL ) AS on_vacation ,
|
||||
bool_or( f.attacking ) AS attacking
|
||||
FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
|
||||
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
|
||||
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
|
||||
LEFT OUTER JOIN emp.planets ep ON ep.planet_id = p.name_id
|
||||
LEFT OUTER JOIN naming.empire_names en ON en.id = ep.empire_id
|
||||
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id
|
||||
LEFT OUTER JOIN battles.battles b
|
||||
ON b.location_id = p.name_id AND b.last_tick IS NULL
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_FLEET_ARRIVALS'
|
||||
AND f.status = 'AVAILABLE' AND fm.time_left = 1
|
||||
GROUP BY p.name_id , ep.empire_id , f.owner_id , v.status , b.id
|
||||
LOOP
|
||||
-- Fleets owned by the planet's owner are never attacking, same for fleets arriving on
|
||||
-- planets that are on vacation
|
||||
IF rec.fleet_owner = rec.planet_owner OR rec.on_vacation THEN
|
||||
UPDATE fleets.fleets f SET attacking = FALSE
|
||||
FROM fleets.movements m
|
||||
WHERE f.status = 'AVAILABLE' AND f.owner_id = rec.fleet_owner
|
||||
AND f.location_id = rec.planet AND m.fleet_id = f.id AND m.time_left = 1;
|
||||
CONTINUE;
|
||||
END IF;
|
||||
|
||||
-- Check enemy lists
|
||||
PERFORM * FROM emp.enemies
|
||||
WHERE empire = rec.planet_owner AND enemy = rec.fleet_owner;
|
||||
IF FOUND
|
||||
THEN
|
||||
-- Fleet owner in the planet owner's EL
|
||||
UPDATE fleets.fleets f SET attacking = TRUE
|
||||
FROM fleets.movements m
|
||||
WHERE f.status = 'AVAILABLE' AND f.owner_id = rec.fleet_owner
|
||||
AND f.location_id = rec.planet AND m.fleet_id = f.id AND m.time_left = 1;
|
||||
CONTINUE;
|
||||
END IF;
|
||||
|
||||
-- If one of the arriving fleets is attacking, or if the local fleets are already attacking,
|
||||
-- then switch all local or arriving fleets to attack
|
||||
SELECT INTO lstat f.attacking
|
||||
FROM fleets.fleets f
|
||||
LEFT OUTER JOIN fleets.movements fm ON fm.fleet_id = f.id
|
||||
WHERE f.owner_id = rec.fleet_owner AND f.location_id = rec.planet AND fm IS NULL
|
||||
GROUP BY f.attacking;
|
||||
IF ( FOUND AND lstat ) OR rec.attacking
|
||||
THEN
|
||||
SELECT INTO f_ids array_agg( f.id ) FROM fleets.fleets f
|
||||
WHERE f.owner_id = rec.fleet_owner AND f.location_id = rec.planet;
|
||||
PERFORM fleets.set_mode( rec.fleet_owner , f_ids , TRUE );
|
||||
CONTINUE;
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
-- Prepare fleet arrival events
|
||||
CREATE TEMPORARY TABLE fleet_arrivals(
|
||||
loc_id INT ,
|
||||
loc_name VARCHAR(20) ,
|
||||
own_id INT ,
|
||||
own_name VARCHAR(20) ,
|
||||
name VARCHAR(64) ,
|
||||
power BIGINT ,
|
||||
mode BOOLEAN ,
|
||||
src_id INT ,
|
||||
src_name VARCHAR(20)
|
||||
);
|
||||
INSERT INTO fleet_arrivals
|
||||
SELECT f.location_id , ln.name , f.owner_id , fon.name ,
|
||||
f.name , fs.power , f.attacking , fm.source_id , sn.name
|
||||
FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
|
||||
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
|
||||
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
|
||||
INNER JOIN fleets.stats_view fs ON fs.id = f.id
|
||||
INNER JOIN naming.empire_names fon ON fon.id = f.owner_id
|
||||
INNER JOIN naming.map_names ln ON ln.id = f.location_id
|
||||
INNER JOIN naming.map_names sn ON sn.id = fm.source_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_FLEET_ARRIVALS'
|
||||
AND f.status = 'AVAILABLE' AND fm.time_left = 1;
|
||||
|
||||
-- Delete movement records, set redeployment penalties, update battles
|
||||
FOR rec IN SELECT f.id AS fleet , fs.flight_time AS flight_time ,
|
||||
f.attacking AS attacking , b.id AS battle ,
|
||||
f.location_id AS location
|
||||
FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
|
||||
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
|
||||
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
|
||||
INNER JOIN fleets.stats_view fs ON fs.id = f.id
|
||||
LEFT OUTER JOIN battles.battles b
|
||||
ON b.location_id = p.name_id AND b.last_tick IS NULL
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_FLEET_ARRIVALS'
|
||||
AND f.status = 'AVAILABLE' AND fm.time_left = 1
|
||||
LOOP
|
||||
DELETE FROM fleets.movements
|
||||
WHERE fleet_id = rec.fleet;
|
||||
UPDATE fleets.fleets
|
||||
SET status = 'REDEPLOYING' ,
|
||||
penalty = 1 + rec.flight_time * ( CASE WHEN rec.attacking THEN 40 ELSE 10 END )
|
||||
WHERE id = rec.fleet;
|
||||
|
||||
-- Add fleets to battle (will not be executed if battle is NULL)
|
||||
PERFORM battles.add_fleet( rec.battle , rec.fleet , FALSE , c_tick );
|
||||
END LOOP;
|
||||
|
||||
-- Send fleet arrival events
|
||||
PERFORM events.commit_fleet_arrivals( c_tick );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
|
@ -0,0 +1,110 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Game updates - fleet movements
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.process_planet_fleet_movements_updates( c_tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
rpid INT;
|
||||
BEGIN
|
||||
-- Lock all records
|
||||
PERFORM f.id FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
|
||||
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
|
||||
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
|
||||
INNER JOIN emp.empires e ON e.name_id = f.owner_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_FLEET_MOVEMENTS'
|
||||
AND f.status = 'AVAILABLE'
|
||||
FOR UPDATE;
|
||||
|
||||
-- Handle state transitions
|
||||
FOR rec IN SELECT f.id AS id , max( fsd.flight_time ) AS flight_time ,
|
||||
s.x AS x , s.y AS y , s.id AS sys_id ,
|
||||
isms.ref_point_id AS is_ref_point , isms.outwards AS is_outwards ,
|
||||
isms.past_ref_point AS is_past_ref_point ,
|
||||
rp.system_id AS is_ref_point_system , rp.orbit AS is_ref_point_orbit ,
|
||||
rps.x AS is_ref_point_x , rps.y AS is_ref_point_y
|
||||
FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
|
||||
INNER JOIN verse.systems s ON s.id = p.system_id
|
||||
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
|
||||
INNER JOIN fleets.ships fs ON fs.fleet_id = f.id
|
||||
INNER JOIN tech.ships fsd ON fsd.buildable_id = fs.ship_id
|
||||
INNER JOIN fleets.movements m ON m.fleet_id = f.id
|
||||
LEFT OUTER JOIN fleets.ms_system isms ON isms.movement_id = f.id
|
||||
LEFT OUTER JOIN verse.planets rp ON isms.ref_point_id = rp.name_id
|
||||
LEFT OUTER JOIN verse.systems rps ON rps.id = rp.system_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_FLEET_MOVEMENTS'
|
||||
AND f.status = 'AVAILABLE' AND m.state_time_left = 1
|
||||
GROUP BY f.id , s.x , s.y , s.id , isms.ref_point_id , isms.outwards ,
|
||||
isms.past_ref_point , rp.system_id , rp.orbit , rps.x , rps.y
|
||||
LOOP
|
||||
IF rec.is_ref_point_orbit IS NOT NULL THEN
|
||||
IF rec.is_ref_point_orbit = 5 AND rec.is_outwards AND rec.is_past_ref_point THEN
|
||||
-- Fleet exiting system
|
||||
INSERT INTO fleets.ms_space ( movement_id , start_x , start_y )
|
||||
VALUES ( rec.id , rec.is_ref_point_x , rec.is_ref_point_y );
|
||||
DELETE FROM fleets.ms_system WHERE movement_id = rec.id;
|
||||
UPDATE fleets.movements
|
||||
SET state_time_left = 1 + fleets.compute_outerspace_duration(
|
||||
rec.flight_time , rec.is_ref_point_x , rec.is_ref_point_y , rec.x , rec.y )
|
||||
WHERE fleet_id = rec.id;
|
||||
ELSE
|
||||
-- In-system state change
|
||||
IF rec.is_past_ref_point THEN
|
||||
SELECT INTO rpid p.name_id FROM verse.planets p
|
||||
WHERE p.system_id = rec.is_ref_point_system
|
||||
AND p.orbit = rec.is_ref_point_orbit + ( CASE WHEN rec.is_outwards THEN 1 ELSE -1 END );
|
||||
UPDATE fleets.ms_system
|
||||
SET past_ref_point = FALSE , ref_point_id = rpid
|
||||
WHERE movement_id = rec.id;
|
||||
ELSE
|
||||
UPDATE fleets.ms_system SET past_ref_point = TRUE
|
||||
WHERE movement_id = rec.id;
|
||||
END IF;
|
||||
UPDATE fleets.movements
|
||||
SET state_time_left = rec.flight_time + 1
|
||||
WHERE fleet_id = rec.id;
|
||||
END IF;
|
||||
ELSE
|
||||
-- Fleet entering system
|
||||
SELECT INTO rpid p.name_id FROM verse.planets p
|
||||
WHERE p.system_id = rec.sys_id AND p.orbit = 5;
|
||||
INSERT INTO fleets.ms_system ( movement_id , ref_point_id , outwards , past_ref_point )
|
||||
VALUES ( rec.id , rpid , FALSE , FALSE );
|
||||
DELETE FROM fleets.ms_space WHERE movement_id = rec.id;
|
||||
UPDATE fleets.movements
|
||||
SET state_time_left = rec.flight_time + 1
|
||||
WHERE fleet_id = rec.id;
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
-- Decrease movement and state time
|
||||
UPDATE fleets.movements
|
||||
SET state_time_left = state_time_left - 1 ,
|
||||
time_left = time_left - 1
|
||||
WHERE fleet_id IN (
|
||||
SELECT f.id FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
|
||||
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
|
||||
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
|
||||
INNER JOIN emp.empires e ON e.name_id = f.owner_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_FLEET_MOVEMENTS'
|
||||
AND f.status = 'AVAILABLE' );
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
|
@ -0,0 +1,77 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Game updates - fleet status
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.process_planet_fleet_status_updates( c_tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
mt_id BIGINT;
|
||||
BEGIN
|
||||
-- Lock all records
|
||||
PERFORM f.id FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
|
||||
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
|
||||
INNER JOIN emp.empires e ON e.name_id = f.owner_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_FLEET_STATUS'
|
||||
FOR UPDATE;
|
||||
|
||||
-- Fleet deployments
|
||||
FOR rec IN SELECT f.id AS fleet , f.owner_id AS owner , f.location_id AS location ,
|
||||
b.id AS battle
|
||||
FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN fleets.fleets f ON f.location_id = vu.planet_id
|
||||
AND f.status = 'DEPLOYING' AND f.penalty = 1
|
||||
INNER JOIN emp.empires e ON e.name_id = f.owner_id
|
||||
LEFT OUTER JOIN battles.battles b
|
||||
ON b.location_id = f.location_id AND b.last_tick IS NULL
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_FLEET_STATUS'
|
||||
LOOP
|
||||
-- Add fleet to battle (will be ignored if battle is NULL)
|
||||
PERFORM battles.add_fleet( rec.battle , rec.fleet , TRUE , c_tick );
|
||||
|
||||
-- Find the biggest available fleet belonging to that owner
|
||||
SELECT INTO mt_id f.id
|
||||
FROM fleets.fleets f
|
||||
INNER JOIN fleets.ships s ON s.fleet_id = f.id
|
||||
INNER JOIN tech.ships sd ON sd.buildable_id = s.ship_id
|
||||
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
|
||||
WHERE f.owner_id = rec.owner AND f.location_id = rec.location
|
||||
AND m.fleet_id IS NULL AND f.status = 'AVAILABLE'
|
||||
GROUP BY f.id
|
||||
ORDER BY sum( sd.power * s.amount ) DESC
|
||||
LIMIT 1;
|
||||
CONTINUE WHEN NOT FOUND;
|
||||
|
||||
-- Merge fleet
|
||||
PERFORM fleets.merge_ships( mt_id , rec.fleet );
|
||||
DELETE FROM fleets.fleets WHERE id = rec.fleet;
|
||||
END LOOP;
|
||||
|
||||
-- Fleets that must become available
|
||||
UPDATE fleets.fleets f SET status = 'AVAILABLE' , penalty = 0
|
||||
FROM sys.updates su , verse.updates vu
|
||||
WHERE vu.update_id = su.id AND f.location_id = vu.planet_id
|
||||
AND f.penalty = 1 AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_FLEET_STATUS' AND su.last_tick = c_tick;
|
||||
|
||||
-- Fleets that still have a penalty
|
||||
UPDATE fleets.fleets f SET penalty = penalty - 1
|
||||
FROM sys.updates su , verse.updates vu
|
||||
WHERE vu.update_id = su.id AND f.location_id = vu.planet_id
|
||||
AND f.penalty > 1 AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_FLEET_STATUS' AND su.last_tick = c_tick;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
|
@ -0,0 +1,181 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Game updates - battles (start, main computation, end)
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.process_planet_battle_start_updates( c_tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
p_id INT;
|
||||
BEGIN
|
||||
FOR p_id IN SELECT p.name_id
|
||||
FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
|
||||
LEFT OUTER JOIN battles.battles b
|
||||
ON b.location_id = p.name_id AND b.last_tick IS NULL
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_BATTLE_START' AND b.location_id IS NULL
|
||||
FOR UPDATE OF p
|
||||
LOOP
|
||||
IF battles.check_start( p_id ) THEN
|
||||
PERFORM events.battle_start_event( battles.initialise( p_id , c_tick ) );
|
||||
END IF;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.process_planet_battle_main_updates( c_tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
ttfi INT;
|
||||
initi REAL;
|
||||
dbonus REAL;
|
||||
dmg REAL;
|
||||
rdmg REAL;
|
||||
rec RECORD;
|
||||
a_power BIGINT;
|
||||
d_power BIGINT;
|
||||
p_power BIGINT;
|
||||
bmod REAL;
|
||||
a_dmg REAL;
|
||||
d_dmg REAL;
|
||||
BEGIN
|
||||
ttfi := floor( sys.get_constant( 'game.battle.timeToFullIntensity' ) )::INT;
|
||||
initi := sys.get_constant( 'game.battle.initialIntensity' );
|
||||
dbonus := sys.get_constant( 'game.battle.defenceBonus');
|
||||
dmg := sys.get_constant( 'game.battle.damage' );
|
||||
rdmg := sys.get_constant( 'game.battle.randomDamage' );
|
||||
|
||||
FOR rec IN SELECT b.id AS battle , b.first_tick AS first_tick ,
|
||||
b.location_id AS location , ( ph.current / p.population )::REAL AS happiness
|
||||
FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
|
||||
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
|
||||
INNER JOIN battles.battles b
|
||||
ON b.location_id = p.name_id AND b.last_tick IS NULL
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_BATTLE_MAIN'
|
||||
FOR UPDATE OF p , b
|
||||
LOOP
|
||||
PERFORM sys.write_log( 'BattleUpdate' , 'DEBUG'::log_level , 'Handling battle #' || rec.battle
|
||||
|| ' at planet #' || rec.location );
|
||||
|
||||
-- Get stationary defence power
|
||||
p_power := floor( verse.adjust_production( verse.get_raw_production( rec.location , 'DEF' ) , rec.happiness ) );
|
||||
|
||||
-- Get fleets power
|
||||
a_power := battles.get_fleets_power( rec.battle , c_tick , TRUE );
|
||||
d_power := battles.get_fleets_power( rec.battle , c_tick , FALSE );
|
||||
IF a_power = 0 OR d_power + p_power = 0
|
||||
THEN
|
||||
PERFORM battles.set_defence_power( rec.battle , c_tick , p_power );
|
||||
CONTINUE;
|
||||
END IF;
|
||||
|
||||
PERFORM sys.write_log( 'BattleUpdate' , 'TRACE'::log_level , 'Attack: ' || a_power
|
||||
|| '; planetary defences: ' || p_power || '; defence: ' || d_power );
|
||||
|
||||
-- Compute battle intensity
|
||||
IF c_tick - rec.first_tick < ttfi THEN
|
||||
bmod := initi + ( 1 - initi ) * ( c_tick - rec.first_tick ) / ttfi;
|
||||
ELSE
|
||||
bmod := 1.0;
|
||||
END IF;
|
||||
PERFORM sys.write_log( 'BattleUpdate' , 'TRACE'::log_level , 'Intensity modifier: ' || bmod );
|
||||
|
||||
-- Compute damage
|
||||
d_dmg := bmod * ( d_power * ( 1 + dbonus ) + p_power ) * dmg * ( 1 - rdmg + 2.0 * rdmg * random() );
|
||||
a_dmg := bmod * a_power * dmg * ( 1 - rdmg + 2.0 * rdmg * random() );
|
||||
PERFORM sys.write_log( 'BattleUpdate' , 'TRACE'::log_level , 'Damage - to defence: ' || a_dmg
|
||||
|| '; to attack: ' || d_dmg );
|
||||
|
||||
-- Inflict damage
|
||||
PERFORM battles.inflict_damage( rec.battle , a_dmg , FALSE , c_tick );
|
||||
PERFORM battles.inflict_damage( rec.battle , d_dmg , TRUE , c_tick );
|
||||
|
||||
-- Update defence power
|
||||
p_power := floor( verse.adjust_production( verse.get_raw_production( rec.location , 'DEF' ) , rec.happiness ) );
|
||||
PERFORM battles.set_defence_power( rec.battle , c_tick , p_power );
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.process_planet_battle_end_updates( c_tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
n_owner INT;
|
||||
BEGIN
|
||||
FOR rec IN SELECT b.id AS battle , b.location_id AS location
|
||||
FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
|
||||
INNER JOIN battles.battles b
|
||||
ON b.location_id = p.name_id AND b.last_tick IS NULL
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_BATTLE_END'
|
||||
FOR UPDATE OF p , b
|
||||
LOOP
|
||||
IF battles.get_fleets_power( rec.battle , c_tick , TRUE ) = 0 THEN
|
||||
-- Attack is dead/gone, end the battle
|
||||
UPDATE battles.battles SET last_tick = c_tick
|
||||
WHERE id = rec.battle;
|
||||
PERFORM events.battle_end_event( rec.battle );
|
||||
ELSEIF battles.get_fleets_power( rec.battle , c_tick , FALSE ) + battles.get_defence_power( rec.battle , c_tick ) = 0 THEN
|
||||
-- Defence is dead/gone, transfer planet ownership to biggest fleet owner
|
||||
n_owner := battles.get_biggest_fleet_owner( rec.battle , c_tick );
|
||||
PERFORM events.planet_ochange_events( rec.location , n_owner );
|
||||
PERFORM emp.leave_planet( rec.location );
|
||||
INSERT INTO emp.planets( planet_id , empire_id )
|
||||
VALUES( rec.location , n_owner );
|
||||
|
||||
-- End the battle
|
||||
UPDATE battles.battles SET last_tick = c_tick
|
||||
WHERE id = rec.battle;
|
||||
PERFORM events.battle_end_event( rec.battle );
|
||||
|
||||
-- Set fleets in orbit to defence if they're not on the new owner's enemy list
|
||||
UPDATE fleets.fleets f SET attacking = ( ele.empire IS NOT NULL )
|
||||
FROM fleets.fleets f2
|
||||
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f2.id
|
||||
LEFT OUTER JOIN emp.enemies ele ON ele.enemy = f2.owner_id AND ele.empire = n_owner
|
||||
WHERE f.id = f2.id AND f.location_id = rec.location AND m.fleet_id IS NULL;
|
||||
|
||||
-- Check if the battle needs to be restarted
|
||||
IF battles.check_start( rec.location ) THEN
|
||||
PERFORM events.battle_start_event( battles.initialise( rec.location , c_tick ) );
|
||||
END IF;
|
||||
ELSE
|
||||
CONTINUE;
|
||||
END IF;
|
||||
|
||||
-- Mark the end of the battle
|
||||
INSERT INTO battles.finished_battles_list
|
||||
SELECT empire, battle, planet, x, y, orbit, name, first_tick, last_tick, last_update
|
||||
FROM battles.full_battles_list
|
||||
WHERE battle = rec.battle;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
|
@ -0,0 +1,48 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Game updates - abandon
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.process_planet_abandon_updates( c_tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
p_id INT;
|
||||
BEGIN
|
||||
-- Lock all records
|
||||
PERFORM p.name_id FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
|
||||
INNER JOIN emp.planets ep ON p.name_id = vu.planet_id
|
||||
INNER JOIN emp.empires e ON e.name_id = ep.empire_id
|
||||
INNER JOIN emp.abandon a ON a.planet_id = p.name_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_ABANDON'
|
||||
FOR UPDATE;
|
||||
|
||||
-- Handle planets where time has run out
|
||||
FOR p_id IN SELECT p.name_id
|
||||
FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
|
||||
INNER JOIN emp.abandon a ON a.planet_id = p.name_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_ABANDON' AND a.time_left = 1
|
||||
LOOP
|
||||
PERFORM emp.leave_planet( p_id );
|
||||
END LOOP;
|
||||
|
||||
-- Update all abandon records
|
||||
UPDATE emp.abandon a SET time_left = a.time_left - 1
|
||||
FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_ABANDON' AND a.planet_id = vu.planet_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
|
@ -0,0 +1,217 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Game updates - buildings construction and destruction
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.process_planet_construction_updates( c_tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
wu_per_pop REAL;
|
||||
dest_work REAL;
|
||||
dest_rec REAL;
|
||||
cur_empire INT;
|
||||
cur_cash REAL;
|
||||
cur_planet INT;
|
||||
p_finished BOOLEAN;
|
||||
cur_wus REAL;
|
||||
cur_acc_c REAL;
|
||||
n_found INT;
|
||||
n_removed INT;
|
||||
i_work REAL;
|
||||
i_cost REAL;
|
||||
can_do REAL;
|
||||
must_do INT;
|
||||
BEGIN
|
||||
-- Get constants
|
||||
wu_per_pop := sys.get_constant( 'game.work.wuPerPopUnit' );
|
||||
dest_work := sys.get_constant( 'game.work.destructionWork' );
|
||||
dest_rec := - sys.get_constant( 'game.work.destructionRecovery' );
|
||||
|
||||
-- Enter update loop
|
||||
cur_empire := NULL;
|
||||
cur_planet := NULL;
|
||||
FOR rec IN SELECT p.name_id AS id , p.population AS pop ,
|
||||
( ph.current / p.population )::REAL AS happiness ,
|
||||
e.name_id AS owner , e.cash AS cash ,
|
||||
q.money AS acc_cash , q.work AS acc_work ,
|
||||
qi.queue_order AS qorder , qi.amount AS amount ,
|
||||
qi.destroy AS destroy , qi.building_id AS building ,
|
||||
b.work AS req_work , b.cost AS req_cost
|
||||
FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
|
||||
INNER JOIN emp.planets ep ON ep.planet_id = p.name_id
|
||||
INNER JOIN emp.empires e ON e.name_id = ep.empire_id
|
||||
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
|
||||
INNER JOIN verse.bld_queues q ON q.planet_id = p.name_id
|
||||
INNER JOIN verse.bld_items qi ON qi.queue_id = q.planet_id
|
||||
INNER JOIN tech.buildables b ON b.name_id = qi.building_id
|
||||
INNER JOIN naming.empire_names en ON en.id = e.name_id
|
||||
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_CONSTRUCTION'
|
||||
AND ( v.account_id IS NULL OR v.status <> 'PROCESSED' )
|
||||
ORDER BY e.name_id , p.name_id , qi.queue_order
|
||||
FOR UPDATE OF p , e , q , qi
|
||||
LOOP
|
||||
-- Update accumulated work and money for the previous planet
|
||||
IF cur_planet IS NOT NULL AND cur_planet <> rec.id THEN
|
||||
IF n_found = n_removed THEN
|
||||
cur_wus := 0;
|
||||
cur_acc_c := 0;
|
||||
PERFORM events.empty_queue_events( cur_empire , cur_planet , FALSE , c_tick );
|
||||
END IF;
|
||||
|
||||
UPDATE verse.bld_queues
|
||||
SET money = cur_acc_c , work = cur_wus
|
||||
WHERE planet_id = cur_planet;
|
||||
cur_cash := cur_cash - cur_acc_c;
|
||||
|
||||
IF cur_cash < 0 THEN
|
||||
cur_cash := 0;
|
||||
END IF;
|
||||
|
||||
cur_planet := NULL;
|
||||
END IF;
|
||||
|
||||
-- Update cash of the previous empire
|
||||
IF cur_empire IS NOT NULL AND cur_empire <> rec.owner
|
||||
THEN
|
||||
UPDATE emp.empires SET cash = cur_cash
|
||||
WHERE name_id = cur_empire;
|
||||
cur_empire := NULL;
|
||||
END IF;
|
||||
|
||||
-- If this is the first record or if the empire changed...
|
||||
IF cur_empire IS NULL THEN
|
||||
cur_empire := rec.owner;
|
||||
cur_cash := rec.cash;
|
||||
END IF;
|
||||
|
||||
-- If this is the first record or if the planet changed...
|
||||
IF cur_planet IS NULL THEN
|
||||
cur_planet := rec.id;
|
||||
cur_cash := cur_cash + rec.acc_cash;
|
||||
cur_wus := rec.acc_work + verse.adjust_production(
|
||||
( rec.pop * wu_per_pop )::REAL ,
|
||||
rec.happiness
|
||||
);
|
||||
n_found := 1;
|
||||
n_removed := 0;
|
||||
cur_acc_c := 0;
|
||||
p_finished := FALSE;
|
||||
ELSE
|
||||
n_found := n_found + 1;
|
||||
END IF;
|
||||
|
||||
-- If we're done updating this planet but there were more items...
|
||||
IF p_finished THEN
|
||||
IF n_removed > 0 THEN
|
||||
UPDATE verse.bld_items
|
||||
SET queue_order = rec.qorder - n_removed
|
||||
WHERE queue_order = rec.qorder AND queue_id = rec.id;
|
||||
END IF;
|
||||
CONTINUE;
|
||||
END IF;
|
||||
|
||||
-- Compute the actual cost and required work of the item
|
||||
i_cost := rec.req_cost * ( CASE WHEN rec.destroy THEN dest_rec ELSE 1.0 END );
|
||||
i_work := rec.req_work * ( CASE WHEN rec.destroy THEN dest_work ELSE 1.0 END );
|
||||
|
||||
-- Compute how many items can be completed
|
||||
can_do := cur_wus / i_work;
|
||||
IF i_cost > 0 AND cur_cash / i_cost < can_do THEN
|
||||
can_do := cur_cash / i_cost;
|
||||
cur_wus := i_work * can_do;
|
||||
END IF;
|
||||
|
||||
-- If we can't build anything at this point...
|
||||
IF can_do < 1 THEN
|
||||
-- Set accumulated cash
|
||||
IF i_cost > 0 THEN
|
||||
cur_acc_c := can_do * i_cost;
|
||||
END IF;
|
||||
|
||||
-- Still update queue item if some items were removed
|
||||
IF n_removed > 0 THEN
|
||||
UPDATE verse.bld_items
|
||||
SET queue_order = rec.qorder - n_removed
|
||||
WHERE queue_order = rec.qorder AND queue_id = rec.id;
|
||||
END IF;
|
||||
|
||||
-- Done with this planet
|
||||
p_finished := TRUE;
|
||||
CONTINUE;
|
||||
END IF;
|
||||
|
||||
-- Compute how many actual items can be built
|
||||
must_do := floor( can_do );
|
||||
IF must_do >= rec.amount THEN
|
||||
must_do := rec.amount;
|
||||
can_do := 0;
|
||||
n_removed := n_removed + 1;
|
||||
END IF;
|
||||
|
||||
-- Handle construction / destruction
|
||||
IF rec.destroy THEN
|
||||
must_do := verse.do_destroy_buildings( rec.id , rec.building , must_do );
|
||||
PERFORM battles.remove_buildings( rec.id , rec.building , must_do , FALSE , c_tick + 1 );
|
||||
ELSE
|
||||
PERFORM verse.do_construct_buildings( rec.id , rec.building , must_do );
|
||||
PERFORM battles.add_buildings( rec.id , rec.building , must_do , c_tick + 1 );
|
||||
END IF;
|
||||
cur_cash := cur_cash - must_do * i_cost;
|
||||
cur_wus := cur_wus - must_do * i_work;
|
||||
|
||||
-- Check whether we're done with this queue
|
||||
IF rec.qorder < n_removed THEN
|
||||
-- Delete queue item
|
||||
DELETE FROM verse.bld_items
|
||||
WHERE queue_order = rec.qorder AND queue_id = rec.id;
|
||||
ELSE
|
||||
-- Update queue item
|
||||
UPDATE verse.bld_items
|
||||
SET queue_order = queue_order - n_removed ,
|
||||
amount = amount - floor( can_do )
|
||||
WHERE queue_order = rec.qorder AND queue_id = rec.id;
|
||||
|
||||
-- Set accumulated cash
|
||||
IF i_cost > 0 THEN
|
||||
cur_acc_c := ( can_do - floor( can_do ) ) * i_cost;
|
||||
END IF;
|
||||
|
||||
p_finished := TRUE;
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
-- If a planet was being procesed, update it and the empire
|
||||
IF cur_planet IS NOT NULL THEN
|
||||
IF n_found = n_removed THEN
|
||||
cur_wus := 0;
|
||||
cur_acc_c := 0;
|
||||
PERFORM events.empty_queue_events( cur_empire , cur_planet , FALSE , c_tick );
|
||||
END IF;
|
||||
|
||||
UPDATE verse.bld_queues
|
||||
SET money = cur_acc_c , work = cur_wus
|
||||
WHERE planet_id = cur_planet;
|
||||
cur_cash := cur_cash - cur_acc_c;
|
||||
|
||||
IF cur_cash < 0 THEN
|
||||
cur_cash := 0;
|
||||
END IF;
|
||||
|
||||
UPDATE emp.empires SET cash = cur_cash
|
||||
WHERE name_id = cur_empire;
|
||||
cur_empire := NULL;
|
||||
END IF;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
|
@ -0,0 +1,227 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Game updates - ship construction
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.process_planet_military_updates( c_tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
cur_empire INT;
|
||||
cur_cash REAL;
|
||||
cur_planet INT;
|
||||
p_finished BOOLEAN;
|
||||
cur_wus REAL;
|
||||
cur_acc_c REAL;
|
||||
n_found INT;
|
||||
n_removed INT;
|
||||
can_do REAL;
|
||||
must_do INT;
|
||||
fl_id BIGINT;
|
||||
BEGIN
|
||||
-- Create temporary table for built ships
|
||||
CREATE TEMPORARY TABLE blt_ships(
|
||||
location INT ,
|
||||
owner INT ,
|
||||
ship INT ,
|
||||
amount INT
|
||||
);
|
||||
|
||||
-- Enter update loop
|
||||
cur_empire := NULL;
|
||||
cur_planet := NULL;
|
||||
FOR rec IN SELECT p.name_id AS id ,
|
||||
( ph.current / p.population )::REAL AS happiness ,
|
||||
e.name_id AS owner , e.cash AS cash ,
|
||||
q.money AS acc_cash , q.work AS acc_work ,
|
||||
qi.queue_order AS qorder , qi.amount AS amount ,
|
||||
qi.ship_id AS ship , s.work AS req_work , s.cost AS req_cost
|
||||
FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
|
||||
INNER JOIN emp.planets ep ON ep.planet_id = p.name_id
|
||||
INNER JOIN emp.empires e ON e.name_id = ep.empire_id
|
||||
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
|
||||
INNER JOIN verse.mil_queues q ON q.planet_id = p.name_id
|
||||
INNER JOIN verse.mil_items qi ON qi.queue_id = q.planet_id
|
||||
INNER JOIN tech.buildables s ON s.name_id = qi.ship_id
|
||||
INNER JOIN naming.empire_names en ON en.id = e.name_id
|
||||
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_MILITARY'
|
||||
AND ( v.account_id IS NULL OR v.status <> 'PROCESSED' )
|
||||
ORDER BY e.name_id , p.name_id , qi.queue_order
|
||||
FOR UPDATE OF p , e , q , qi
|
||||
LOOP
|
||||
-- Update accumulated work and money for the previous planet
|
||||
IF cur_planet IS NOT NULL AND cur_planet <> rec.id THEN
|
||||
IF n_found = n_removed THEN
|
||||
cur_wus := 0;
|
||||
cur_acc_c := 0;
|
||||
PERFORM events.empty_queue_events( cur_empire , cur_planet , TRUE , c_tick );
|
||||
END IF;
|
||||
|
||||
UPDATE verse.mil_queues
|
||||
SET money = cur_acc_c , work = cur_wus
|
||||
WHERE planet_id = cur_planet;
|
||||
cur_cash := cur_cash - cur_acc_c;
|
||||
|
||||
IF cur_cash < 0 THEN
|
||||
cur_cash := 0;
|
||||
END IF;
|
||||
|
||||
cur_planet := NULL;
|
||||
END IF;
|
||||
|
||||
-- Update cash of the previous empire
|
||||
IF cur_empire IS NOT NULL AND cur_empire <> rec.owner
|
||||
THEN
|
||||
UPDATE emp.empires SET cash = cur_cash
|
||||
WHERE name_id = cur_empire;
|
||||
cur_empire := NULL;
|
||||
END IF;
|
||||
|
||||
-- If this is the first record or if the empire changed...
|
||||
IF cur_empire IS NULL THEN
|
||||
cur_empire := rec.owner;
|
||||
cur_cash := rec.cash;
|
||||
END IF;
|
||||
|
||||
-- If this is the first record or if the planet changed...
|
||||
IF cur_planet IS NULL THEN
|
||||
cur_planet := rec.id;
|
||||
cur_cash := cur_cash + rec.acc_cash;
|
||||
cur_wus := rec.acc_work + verse.adjust_production(
|
||||
verse.get_raw_production( rec.id , 'WORK' ) ,
|
||||
rec.happiness
|
||||
);
|
||||
n_found := 1;
|
||||
n_removed := 0;
|
||||
cur_acc_c := 0;
|
||||
p_finished := FALSE;
|
||||
ELSE
|
||||
n_found := n_found + 1;
|
||||
END IF;
|
||||
|
||||
-- If we're done updating this planet but there were more items...
|
||||
IF p_finished THEN
|
||||
IF n_removed > 0 THEN
|
||||
UPDATE verse.mil_items
|
||||
SET queue_order = rec.qorder - n_removed
|
||||
WHERE queue_order = rec.qorder AND queue_id = rec.id;
|
||||
END IF;
|
||||
CONTINUE;
|
||||
END IF;
|
||||
|
||||
-- Compute how many items can be completed
|
||||
can_do := cur_wus / rec.req_work;
|
||||
IF cur_cash / rec.req_cost < can_do THEN
|
||||
can_do := cur_cash / rec.req_cost;
|
||||
cur_wus := rec.req_work * can_do;
|
||||
END IF;
|
||||
|
||||
-- If we can't build anything at this point...
|
||||
IF can_do < 1 THEN
|
||||
-- Set accumulated cash
|
||||
cur_acc_c := can_do * rec.req_cost;
|
||||
|
||||
-- Still update queue item if some items were removed
|
||||
IF n_removed > 0 THEN
|
||||
UPDATE verse.mil_items
|
||||
SET queue_order = rec.qorder - n_removed
|
||||
WHERE queue_order = rec.qorder AND queue_id = rec.id;
|
||||
END IF;
|
||||
|
||||
-- Done with this planet
|
||||
p_finished := TRUE;
|
||||
CONTINUE;
|
||||
END IF;
|
||||
|
||||
-- Compute how many actual items can be built
|
||||
must_do := floor( can_do );
|
||||
IF must_do >= rec.amount THEN
|
||||
must_do := rec.amount;
|
||||
can_do := 0;
|
||||
n_removed := n_removed + 1;
|
||||
END IF;
|
||||
|
||||
-- Handle construction
|
||||
INSERT INTO blt_ships( location , owner , ship , amount)
|
||||
VALUES ( rec.id , rec.owner , rec.ship , must_do );
|
||||
cur_cash := cur_cash - must_do * rec.req_cost;
|
||||
cur_wus := cur_wus - must_do * rec.req_work;
|
||||
|
||||
-- Check whether we're done with this queue
|
||||
IF rec.qorder < n_removed THEN
|
||||
-- Delete queue item
|
||||
DELETE FROM verse.mil_items
|
||||
WHERE queue_order = rec.qorder AND queue_id = rec.id;
|
||||
ELSE
|
||||
-- Update queue item
|
||||
UPDATE verse.mil_items
|
||||
SET queue_order = queue_order - n_removed ,
|
||||
amount = amount - must_do
|
||||
WHERE queue_order = rec.qorder AND queue_id = rec.id;
|
||||
|
||||
-- Set accumulated cash
|
||||
cur_acc_c := ( can_do - floor( can_do ) ) * rec.req_cost;
|
||||
|
||||
p_finished := TRUE;
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
-- If a planet was being procesed, update it and the empire
|
||||
IF cur_planet IS NOT NULL THEN
|
||||
IF n_found = n_removed THEN
|
||||
cur_wus := 0;
|
||||
cur_acc_c := 0;
|
||||
PERFORM events.empty_queue_events( cur_empire , cur_planet , TRUE , c_tick );
|
||||
END IF;
|
||||
|
||||
UPDATE verse.mil_queues
|
||||
SET money = cur_acc_c , work = cur_wus
|
||||
WHERE planet_id = cur_planet;
|
||||
cur_cash := cur_cash - cur_acc_c;
|
||||
|
||||
IF cur_cash < 0 THEN
|
||||
cur_cash := 0;
|
||||
END IF;
|
||||
|
||||
UPDATE emp.empires SET cash = cur_cash
|
||||
WHERE name_id = cur_empire;
|
||||
cur_empire := NULL;
|
||||
END IF;
|
||||
|
||||
-- Spawn fleets
|
||||
FOR cur_planet , cur_empire IN SELECT DISTINCT location , owner FROM blt_ships
|
||||
LOOP
|
||||
-- Get fleet's flight time
|
||||
SELECT INTO must_do MAX( s.flight_time )
|
||||
FROM blt_ships b
|
||||
INNER JOIN tech.ships s ON s.buildable_id = b.ship
|
||||
WHERE b.location = cur_planet AND b.owner = cur_empire;
|
||||
|
||||
-- Insert the fleet
|
||||
INSERT INTO fleets.fleets (owner_id, location_id , attacking , status , penalty )
|
||||
VALUES ( cur_empire , cur_planet , FALSE , 'DEPLOYING' , must_do * 2 )
|
||||
RETURNING id INTO fl_id;
|
||||
|
||||
-- Insert ships
|
||||
INSERT INTO fleets.ships ( fleet_id , ship_id , amount , damage )
|
||||
SELECT fl_id , b.ship , sum( b.amount ) , 0
|
||||
FROM blt_ships b
|
||||
WHERE b.location = cur_planet AND b.owner = cur_empire
|
||||
GROUP BY b.ship;
|
||||
END LOOP;
|
||||
|
||||
-- Destroy temporary table
|
||||
DROP TABLE blt_ships;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
|
@ -0,0 +1,104 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Game updates - population growth and happiness
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.process_planet_population_updates( c_tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
rel_ch REAL;
|
||||
abs_ch REAL;
|
||||
g_fact REAL;
|
||||
gf_inc REAL;
|
||||
n_happ REAL;
|
||||
t_happ REAL;
|
||||
temp REAL;
|
||||
growth REAL;
|
||||
workers REAL;
|
||||
str_thr REAL;
|
||||
BEGIN
|
||||
-- Get constants
|
||||
rel_ch := sys.get_constant( 'game.happiness.relativeChange' );
|
||||
abs_ch := sys.get_constant( 'game.happiness.maxAbsoluteChange' );
|
||||
g_fact := sys.get_constant( 'game.growthFactor' );
|
||||
gf_inc := sys.get_constant( 'game.growthFactor.rCentre' );
|
||||
str_thr := sys.get_constant( 'game.happiness.strike' );
|
||||
|
||||
-- Process planets
|
||||
FOR rec IN SELECT p.name_id AS id , p.population AS pop ,
|
||||
ph.target AS target , ph.current AS happy_pop ,
|
||||
( ph.current / p.population )::REAL AS current
|
||||
FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
|
||||
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_POPULATION'
|
||||
FOR UPDATE OF p, ph
|
||||
LOOP
|
||||
IF round( rec.target / rel_ch ) = round( rec.current / rel_ch ) THEN
|
||||
-- Happiness does not change
|
||||
n_happ := rec.current;
|
||||
ELSE
|
||||
-- Compute new happiness
|
||||
temp := rec.pop * rel_ch;
|
||||
IF temp > abs_ch THEN
|
||||
temp := abs_ch;
|
||||
ELSEIF temp < 1 THEN
|
||||
temp := 1;
|
||||
END IF;
|
||||
|
||||
IF rec.target < rec.current THEN
|
||||
temp := - temp;
|
||||
END IF;
|
||||
|
||||
n_happ := ( rec.happy_pop + temp ) / rec.pop;
|
||||
END IF;
|
||||
|
||||
-- Compute population growth
|
||||
temp := verse.adjust_production( verse.get_raw_production( rec.id , 'POP' ) , n_happ );
|
||||
growth := ( g_fact + temp * gf_inc ) * n_happ / 1440.0;
|
||||
|
||||
-- Get workers
|
||||
SELECT INTO workers SUM( b.amount * d.workers )
|
||||
FROM verse.planet_buildings b
|
||||
INNER JOIN tech.buildings d
|
||||
ON d.buildable_id = b.building_id
|
||||
WHERE b.planet_id = rec.id;
|
||||
IF workers IS NULL THEN
|
||||
workers := 0;
|
||||
END IF;
|
||||
|
||||
-- Compute new target happiness
|
||||
t_happ := verse.compute_happiness( rec.pop + growth , workers ,
|
||||
verse.adjust_production( verse.get_raw_production( rec.id , 'DEF' ) , n_happ ) ,
|
||||
emp.get_size( rec.id )
|
||||
);
|
||||
|
||||
-- Update planet and happiness records
|
||||
UPDATE verse.planet_happiness
|
||||
SET current = ( rec.pop + growth ) * n_happ , target = t_happ
|
||||
WHERE planet_id = rec.id;
|
||||
UPDATE verse.planets
|
||||
SET population = rec.pop + growth
|
||||
WHERE name_id = rec.id;
|
||||
|
||||
-- Send strike begin/end messages
|
||||
IF n_happ < str_thr AND rec.current >= str_thr
|
||||
THEN
|
||||
PERFORM events.strike_event( rec.id , TRUE );
|
||||
ELSEIF n_happ >= str_thr AND rec.current < str_thr
|
||||
THEN
|
||||
PERFORM events.strike_event( rec.id , FALSE );
|
||||
END IF;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
|
@ -0,0 +1,45 @@
|
|||
-- LegacyWorlds Beta 6
|
||||
-- PostgreSQL database scripts
|
||||
--
|
||||
-- Game updates - planet income and upkeep
|
||||
--
|
||||
-- Copyright(C) 2004-2010, DeepClone Development
|
||||
-- --------------------------------------------------------
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION sys.process_planet_money_updates( c_tick BIGINT )
|
||||
RETURNS VOID
|
||||
STRICT VOLATILE
|
||||
SECURITY INVOKER
|
||||
AS $$
|
||||
DECLARE
|
||||
rec RECORD;
|
||||
incme REAL;
|
||||
BEGIN
|
||||
FOR rec IN SELECT p.name_id AS id , p.population AS pop ,
|
||||
( ph.current / p.population )::REAL AS happiness ,
|
||||
( ea.planet_id IS NULL ) AS produces_income
|
||||
FROM sys.updates su
|
||||
INNER JOIN verse.updates vu ON vu.update_id = su.id
|
||||
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
|
||||
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
|
||||
INNER JOIN verse.planet_money pm ON pm.planet_id = p.name_id
|
||||
LEFT OUTER JOIN emp.abandon ea ON ea.planet_id = p.name_id
|
||||
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
|
||||
AND su.gu_type = 'PLANET_MONEY'
|
||||
FOR UPDATE OF p, pm
|
||||
LOOP
|
||||
IF rec.produces_income THEN
|
||||
incme := verse.compute_income( rec.pop , rec.happiness ,
|
||||
verse.get_raw_production( rec.id , 'CASH' )
|
||||
);
|
||||
ELSE
|
||||
incme := 0;
|
||||
END IF;
|
||||
UPDATE verse.planet_money
|
||||
SET income = incme ,
|
||||
upkeep = verse.get_planet_upkeep( rec.id )
|
||||
WHERE planet_id = rec.id;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
Reference in a new issue