-- 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;