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