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

464 lines
11 KiB
SQL

-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Storage of events (internal messages)
--
-- Copyright(C) 2004-2011, DeepClone Development
-- --------------------------------------------------------
--
-- Event type definitionss
--
CREATE TABLE events.event_type_definitions(
etd_type VARCHAR( 48 ) NOT NULL
PRIMARY KEY ,
etd_priority INT NOT NULL
CHECK( etd_priority BETWEEN 1 AND 5 ) ,
etd_user_priority BOOLEAN NOT NULL
);
--
-- Types of field contents
--
-- INMB integer
-- RNMB real number
-- TEXT text
-- BOOL boolean
-- I18N internationalised string
-- EREF game entity reference
--
CREATE TYPE events.field_content_type
AS ENUM ( 'INMB' , 'RNMB' , 'TEXT' , 'BOOL' , 'I18N' , 'EREF' );
--
-- Subtypes of reference field contents
--
-- EMP empire
-- MAP map object
-- FLT fleet
-- BAT battle
-- ADM administrator
-- MSG message
-- BUG bug report
--
CREATE TYPE events.field_reference_type
AS ENUM ( 'EMP' , 'MAP' , 'FLT' , 'BAT' , 'ADM' , 'MSG' , 'BUG' );
--
-- Event field definitions
--
CREATE TABLE events.event_field_definitions(
etd_type VARCHAR( 48 ) NOT NULL ,
efd_field VARCHAR( 48 ) NOT NULL ,
efd_required BOOLEAN NOT NULL ,
efd_type events.field_content_type NOT NULL ,
efd_reference_type events.field_reference_type ,
efd_low_boundary DOUBLE PRECISION ,
efd_high_boundary DOUBLE PRECISION ,
PRIMARY KEY ( etd_type , efd_field ) ,
CHECK( efd_type = 'EREF' AND efd_reference_type IS NOT NULL
OR efd_type <> 'EREF' AND efd_reference_type IS NULL ) ,
CHECK ( efd_type IN ( 'INMB' , 'RNMB' , 'TEXT' )
OR efd_type NOT IN ( 'INMB' , 'RNMB' , 'TEXT' )
AND efd_low_boundary IS NULL
AND efd_high_boundary IS NULL ) ,
CHECK ( efd_low_boundary IS NULL OR efd_high_boundary IS NULL
OR efd_low_boundary < efd_high_boundary )
);
ALTER TABLE events.event_field_definitions
ADD CONSTRAINT fk_efd_type
FOREIGN KEY ( etd_type ) REFERENCES events.event_type_definitions;
--
-- Event format definitions
--
CREATE TABLE events.event_format_definitions(
etd_type VARCHAR( 48 ) NOT NULL ,
efmd_order INT NOT NULL ,
efmd_template INT NOT NULL ,
PRIMARY KEY ( etd_type , efmd_order )
);
CREATE INDEX idx_efmd_template
ON events.event_format_definitions ( efmd_template );
ALTER TABLE events.event_format_definitions
ADD CONSTRAINT fk_efmd_type
FOREIGN KEY ( etd_type ) REFERENCES events.event_type_definitions ,
ADD CONSTRAINT fk_efmd_template
FOREIGN KEY ( efmd_template ) REFERENCES defs.strings;
--
-- Types of format conditions
--
-- EX has value all
-- EQ is equal to ... all except EREF
-- NE is not equal to ... all except EREF
-- GT > ... INMB , RNMB
-- length > ... TEXT
-- LT < ... INMB , RNMB
-- shorter than ... TEXT
-- GE >= ... INMB , RNMB
-- length >= ... TEXT
-- LE <= ... INMB , RNMB
-- length <= ... TEXT
-- AV available EREF
--
CREATE TYPE events.format_condition_type
AS ENUM ( 'EX' , 'EQ' , 'NE' , 'GT' , 'LT' , 'GE' , 'LE' , 'AV' );
--
-- Conditions on format definitions
--
CREATE TABLE events.efmt_conditions(
etd_type VARCHAR( 48 ) NOT NULL ,
efmd_order INT NOT NULL ,
efd_field VARCHAR( 48 ) NOT NULL ,
efc_type events.format_condition_type NOT NULL ,
efc_boolean BOOLEAN ,
efc_numeric DOUBLE PRECISION ,
efc_string TEXT ,
PRIMARY KEY( etd_type , efmd_order , efd_field , efc_type )
);
CREATE INDEX idx_efmtc_field
ON events.efmt_conditions ( etd_type , efd_field );
ALTER TABLE events.efmt_conditions
ADD CONSTRAINT fk_efmtc_format
FOREIGN KEY ( etd_type , efmd_order ) REFERENCES events.event_format_definitions ,
ADD CONSTRAINT fk_efmtc_field
FOREIGN KEY ( etd_type , efd_field ) REFERENCES events.event_field_definitions;
-- --------------------------------------------------------
-- OLD CODE BELOW
--
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.technologies;
--
-- 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;