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