Events database structure
Added tables allowing event data to be stored on the long term: * events.events_v2 (which will need to be renamed) contains the events' main entry * events.field_values stores field values for all events.
This commit is contained in:
parent
cf8dee6ec9
commit
9e84f333e7
1 changed files with 141 additions and 0 deletions
|
@ -239,6 +239,147 @@ CREATE SEQUENCE events.event_id_sequence;
|
||||||
GRANT SELECT,UPDATE ON events.event_id_sequence TO :dbuser;
|
GRANT SELECT,UPDATE ON events.event_id_sequence TO :dbuser;
|
||||||
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Event storage table
|
||||||
|
* -------------------
|
||||||
|
*
|
||||||
|
* This table stores the main entries for actual events. It is fed using the
|
||||||
|
* various type-specific event queues.
|
||||||
|
*
|
||||||
|
* FIXME: this table should be renamed once the old internal messages are
|
||||||
|
* gone.
|
||||||
|
*/
|
||||||
|
DROP TABLE IF EXISTS events.events_v2 CASCADE;
|
||||||
|
CREATE TABLE events.events_v2(
|
||||||
|
/* Numeric identifier of the event */
|
||||||
|
event_id BIGINT NOT NULL PRIMARY KEY ,
|
||||||
|
|
||||||
|
/* Type of the event */
|
||||||
|
evdef_id VARCHAR( 48 ) NOT NULL ,
|
||||||
|
|
||||||
|
/* Real time at which the event occurred */
|
||||||
|
event_rtime TIMESTAMP WITHOUT TIME ZONE
|
||||||
|
NOT NULL ,
|
||||||
|
|
||||||
|
/* Game time (tick identifier) at which the event occurred */
|
||||||
|
event_gtime BIGINT NOT NULL ,
|
||||||
|
|
||||||
|
/* Identifier of the empire to which the event applies */
|
||||||
|
empire_id INT NOT NULL
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE UNIQUE INDEX idx_events_iddef
|
||||||
|
ON events.events_v2 ( event_id , evdef_id );
|
||||||
|
CREATE INDEX idx_events_selector
|
||||||
|
ON events.events_v2 ( empire_id , event_rtime );
|
||||||
|
|
||||||
|
ALTER TABLE events.events_v2
|
||||||
|
ADD CONSTRAINT fk_events_evdef
|
||||||
|
FOREIGN KEY ( evdef_id ) REFERENCES events.event_definitions ( evdef_id ) ,
|
||||||
|
ADD CONSTRAINT fk_events_empire
|
||||||
|
FOREIGN KEY ( empire_id ) REFERENCES emp.empires ( name_id )
|
||||||
|
ON DELETE CASCADE;
|
||||||
|
|
||||||
|
GRANT SELECT ON events.events_v2 TO :dbuser;
|
||||||
|
|
||||||
|
|
||||||
|
/*
|
||||||
|
* Event field values storage table
|
||||||
|
* --------------------------------
|
||||||
|
*
|
||||||
|
* This table stores the values of the events' fields.
|
||||||
|
*/
|
||||||
|
DROP TABLE IF EXISTS events.field_values CASCADE;
|
||||||
|
CREATE TABLE events.field_values(
|
||||||
|
/* The event's identifier */
|
||||||
|
event_id BIGINT NOT NULL ,
|
||||||
|
|
||||||
|
/* The event's type */
|
||||||
|
evdef_id VARCHAR(48) NOT NULL ,
|
||||||
|
|
||||||
|
/* The field's identifier */
|
||||||
|
efdef_id VARCHAR(48) NOT NULL ,
|
||||||
|
|
||||||
|
/* Literal field value */
|
||||||
|
efval_litteral TEXT NOT NULL ,
|
||||||
|
|
||||||
|
/* I18N string reference */
|
||||||
|
string_id INT ,
|
||||||
|
|
||||||
|
/* Empire reference */
|
||||||
|
empire_id INT ,
|
||||||
|
|
||||||
|
/* Planet reference */
|
||||||
|
planet_id INT ,
|
||||||
|
|
||||||
|
/* Fleet reference */
|
||||||
|
fleet_id BIGINT ,
|
||||||
|
|
||||||
|
/* Alliance reference */
|
||||||
|
alliance_id INT ,
|
||||||
|
|
||||||
|
/* Battle reference */
|
||||||
|
battle_id BIGINT ,
|
||||||
|
|
||||||
|
/* Administrator reference */
|
||||||
|
admin_id INT ,
|
||||||
|
|
||||||
|
/* Bug report reference */
|
||||||
|
bug_report_id BIGINT ,
|
||||||
|
|
||||||
|
PRIMARY KEY( event_id , evdef_id , efdef_id )
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE INDEX idx_fvalues_string
|
||||||
|
ON events.field_values ( string_id );
|
||||||
|
CREATE INDEX idx_fvalues_empire
|
||||||
|
ON events.field_values ( empire_id );
|
||||||
|
CREATE INDEX idx_fvalues_planet
|
||||||
|
ON events.field_values ( planet_id );
|
||||||
|
CREATE INDEX idx_fvalues_fleet
|
||||||
|
ON events.field_values ( fleet_id );
|
||||||
|
CREATE INDEX idx_fvalues_alliance
|
||||||
|
ON events.field_values ( alliance_id );
|
||||||
|
CREATE INDEX idx_fvalues_battle
|
||||||
|
ON events.field_values ( battle_id );
|
||||||
|
CREATE INDEX idx_fvalues_admin
|
||||||
|
ON events.field_values ( admin_id );
|
||||||
|
CREATE INDEX idx_fvalues_bugreport
|
||||||
|
ON events.field_values ( bug_report_id );
|
||||||
|
|
||||||
|
ALTER TABLE events.field_values
|
||||||
|
ADD CONSTRAINT fk_fvalues_event
|
||||||
|
FOREIGN KEY ( event_id , evdef_id ) REFERENCES events.events_v2 ( event_id , evdef_id )
|
||||||
|
ON DELETE CASCADE ,
|
||||||
|
ADD CONSTRAINT fk_fvalues_field
|
||||||
|
FOREIGN KEY ( evdef_id , efdef_id ) REFERENCES events.field_definitions ,
|
||||||
|
ADD CONSTRAINT fk_fvalues_string
|
||||||
|
FOREIGN KEY ( string_id ) REFERENCES defs.strings ,
|
||||||
|
ADD CONSTRAINT fk_fvalues_empire
|
||||||
|
FOREIGN KEY ( empire_id ) REFERENCES emp.empires
|
||||||
|
ON DELETE CASCADE ,
|
||||||
|
ADD CONSTRAINT fk_fvalues_planet
|
||||||
|
FOREIGN KEY ( planet_id ) REFERENCES verse.planets
|
||||||
|
ON DELETE CASCADE ,
|
||||||
|
ADD CONSTRAINT fk_fvalues_fleet
|
||||||
|
FOREIGN KEY ( fleet_id ) REFERENCES fleets.fleets
|
||||||
|
ON DELETE CASCADE ,
|
||||||
|
ADD CONSTRAINT fk_fvalues_alliance
|
||||||
|
FOREIGN KEY ( alliance_id ) REFERENCES emp.alliances
|
||||||
|
ON DELETE CASCADE ,
|
||||||
|
ADD CONSTRAINT fk_fvalues_battle
|
||||||
|
FOREIGN KEY ( battle_id ) REFERENCES battles.battles
|
||||||
|
ON DELETE CASCADE ,
|
||||||
|
ADD CONSTRAINT fk_fvalues_admin
|
||||||
|
FOREIGN KEY ( admin_id ) REFERENCES admin.administrators
|
||||||
|
ON DELETE CASCADE ,
|
||||||
|
ADD CONSTRAINT fk_fvalues_bugreport
|
||||||
|
FOREIGN KEY ( bug_report_id ) REFERENCES bugs.initial_report_events
|
||||||
|
ON DELETE CASCADE;
|
||||||
|
|
||||||
|
GRANT SELECT ON events.field_values TO :dbuser;
|
||||||
|
|
||||||
|
|
||||||
|
|
||||||
/*
|
/*
|
||||||
* OLD B6M1 CODE BELOW!
|
* OLD B6M1 CODE BELOW!
|
||||||
|
|
Reference in a new issue