-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Battle functions and utility views
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------


--
-- Checks if a battle needs to start at a given location
--
-- Parameters:
--	l_id		Location to check
--
-- Returns:
--	Whether or not a new battle is to be added
--

CREATE OR REPLACE FUNCTION battles.check_start( l_id INT )
		RETURNS BOOLEAN
		STRICT STABLE
		SECURITY INVOKER
	AS $$
BEGIN
	PERFORM p.name_id
		FROM verse.planets p
			INNER JOIN fleets.fleets f ON f.location_id = p.name_id AND f.attacking
			LEFT OUTER JOIN fleets.movements m
				ON m.fleet_id = f.id
			LEFT OUTER JOIN battles.battles b
				ON b.location_id = p.name_id AND last_tick IS NULL
		WHERE p.name_id = l_id AND m.fleet_id IS NULL and b.id IS NULL;
	RETURN FOUND;
END;
$$ LANGUAGE plpgsql;


--
-- Creates or returns an empire's battle record
--
-- Parameters:
--	e_id		Empire identifier
--
-- Returns:
--	the empire battle record's identifier
--

CREATE OR REPLACE FUNCTION battles.goc_empire( e_id INT )
		RETURNS BIGINT
		STRICT VOLATILE
		SECURITY INVOKER
	AS $$
DECLARE
	r_id	BIGINT;
BEGIN
	LOOP
		SELECT INTO r_id id FROM battles.empires
				WHERE empire_id = e_id;
		EXIT WHEN FOUND;
		
		INSERT INTO battles.empires ( name , empire_id )
			SELECT name , id FROM naming.empire_names
				WHERE id = e_id
			RETURNING id INTO r_id;

		PERFORM * FROM battles.empires
			WHERE empire_id = e_id AND id <> r_id;
		EXIT WHEN NOT FOUND;

		DELETE FROM battles.empires WHERE id = r_id;
	END LOOP;
	RETURN r_id;
END;
$$ LANGUAGE plpgsql;



--
-- Creates or returns a protagonist's record
--
-- Parameters:
--	b_id		Battle identifier
--	e_id		Empire identifier
--	mode		Protagonist mode
--	tick		Current tick
--

CREATE OR REPLACE FUNCTION battles.goc_protagonist( b_id BIGINT , e_id INT , mode BOOLEAN , tick BIGINT )
		RETURNS BIGINT
		STRICT VOLATILE
		SECURITY INVOKER
	AS $$
DECLARE
	be_id	BIGINT;
	p_id	BIGINT;
	lmode	BOOLEAN;
BEGIN
	be_id := battles.goc_empire( e_id );

	LOOP
		SELECT INTO p_id id FROM battles.protagonists
			WHERE battle_id = b_id AND empire_id = be_id;
		EXIT WHEN FOUND;
		
		BEGIN
			INSERT INTO battles.protagonists ( battle_id , empire_id )
				VALUES ( b_id , be_id )
				RETURNING id INTO p_id;
			EXIT;
		EXCEPTION
			WHEN unique_violation THEN
				-- Do nothing
		END;
	END LOOP;
	
	SELECT INTO lmode attacking
		FROM battles.status_changes WHERE protagonist_id = p_id
		ORDER BY tick_identifier DESC LIMIT 1;
	IF NOT FOUND OR lmode <> mode
	THEN
		INSERT INTO battles.status_changes ( protagonist_id , tick_identifier , attacking )
			VALUES ( p_id , tick , mode );
	END IF;
	
	RETURN p_id;
END;
$$ LANGUAGE plpgsql;



--
-- Initialises a battle record
--
-- Parameters:
--	l_id		Location
--	tick		The current tick's identifier
--
-- Returns:
--	the battle's identifier
--

CREATE OR REPLACE FUNCTION battles.initialise( l_id INT , tick BIGINT )
		RETURNS BIGINT
		STRICT VOLATILE
		SECURITY INVOKER
	AS $$
DECLARE
	-- Battle ID
	b_id	BIGINT;
	-- Battle planet ID
	bp_id	BIGINT;
	-- Record for list operations
	rec		RECORD;
	-- Protagonist ID
	prot_id	BIGINT;
	-- Fleet status record ID
	bf_id	BIGINT;
	-- Planet owner
	po_id	INT;
BEGIN
	-- Create main battle record
	INSERT INTO battles.battles ( location_id , first_tick )
		VALUES ( l_id , tick )
		RETURNING id INTO b_id;

	-- Create planet record
	INSERT INTO battles.planets( battle_id , tick_identifier , change_type , name )
		SELECT b_id , tick , 'INIT'::battle_planet_change , n.name
			FROM naming.map_names n WHERE n.id = l_id
		RETURNING id INTO bp_id;

	-- Insert list of initial buildings
	INSERT INTO battles.buildings ( planet_id , building_id , change )
		SELECT bp_id , b.building_id , b.amount
			FROM verse.planet_buildings b
				INNER JOIN tech.buildings bd ON bd.buildable_id = b.building_id
			WHERE b.planet_id = l_id AND bd.output_type = 'DEF' AND b.amount > 0;

	-- Insert defensive power
	INSERT INTO battles.defences ( battle_id , tick_identifier , power )
		SELECT b_id , tick , floor( verse.adjust_production(
					verse.get_raw_production( p.name_id , 'DEF' ) , ph.current / p.population ) )
			FROM verse.planets p
				INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
			WHERE p.name_id = l_id;

	-- Add protagonists and initial status
	SELECT INTO po_id empire_id FROM emp.planets ep WHERE ep.planet_id = l_id;
	FOR rec IN SELECT f.owner_id AS id , f.attacking AS mode
					FROM fleets.fleets f
						INNER JOIN naming.empire_names n ON n.id = f.owner_id
						LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
					WHERE f.location_id = l_id AND m.fleet_id IS NULL
				UNION SELECT ep.empire_id AS id , FALSE AS mode
					FROM emp.planets ep
					WHERE ep.planet_id = l_id
	LOOP
		prot_id := battles.goc_protagonist( b_id , rec.id , rec.mode , tick );
		IF po_id = rec.id THEN
			INSERT INTO battles.planet_ownership ( protagonist_id )
				VALUES ( prot_id );
		END IF;

		-- Insert fleets
		INSERT INTO battles.fleets ( protagonist_id , tick_identifier , change_type )
			VALUES ( prot_id , tick , 'INIT'::battle_fleet_change )
			RETURNING id INTO bf_id;
		INSERT INTO battles.ships ( fleet_id , ship_id , change )
			SELECT bf_id , s.ship_id , sum( s.amount )
				FROM fleets.fleets f
					INNER JOIN fleets.ships s ON s.fleet_id = f.id
					LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
				WHERE f.owner_id = rec.id AND f.location_id = l_id
					AND m.fleet_id IS NULL AND f.status <> 'DEPLOYING'
				GROUP BY s.ship_id;
	END LOOP;

	RETURN b_id;
END;
$$ LANGUAGE plpgsql;



--
-- Adds fleet ship changes
--

CREATE OR REPLACE FUNCTION battles.add_fleet_change( f_id BIGINT , s_id INT , l_change INT )
		RETURNS VOID
		STRICT VOLATILE
		SECURITY INVOKER
	AS $$
BEGIN
	LOOP
		UPDATE battles.ships SET change = change + l_change
			WHERE fleet_id = f_id AND ship_id = s_id;
		EXIT WHEN FOUND;

		BEGIN
			INSERT INTO battles.ships ( fleet_id , ship_id , change )
				VALUES ( f_id , s_id , l_change );
			EXIT;
		EXCEPTION
			WHEN unique_violation THEN
				-- Do nothing
		END;
	END LOOP;
END;
$$ LANGUAGE plpgsql;



--
-- Gets or create a planet's change record
--
-- Parameters:
--	b_id		Battle identifier
--	ctype		Change type
--	tick		Tick identifier
--
-- Returns:
--	the planet's change record
--

CREATE OR REPLACE FUNCTION battles.goc_planet( b_id BIGINT , ctype battle_planet_change , tick BIGINT )
		RETURNS BIGINT
		STRICT VOLATILE
		SECURITY INVOKER
	AS $$
DECLARE
	pr_id	BIGINT;
BEGIN
	LOOP
		SELECT INTO pr_id id FROM battles.planets
			WHERE battle_id = b_id AND change_type = ctype
				AND tick_identifier = tick;
		EXIT WHEN FOUND;
		
		BEGIN
			INSERT INTO battles.planets( battle_id , tick_identifier , change_type )
				VALUES ( b_id , tick , ctype )
				RETURNING id INTO pr_id;
			EXIT;
		EXCEPTION
			WHEN unique_violation THEN
				-- Do nothing
		END;
	END LOOP;
	
	RETURN pr_id;
END;
$$ LANGUAGE plpgsql;



--
-- Records building changes
--
-- Parameters:
--	pcr_id		Planet change record
--	bt_id		Building type
--	amount		Amount
--

CREATE OR REPLACE FUNCTION battles.record_building_change( pcr_id BIGINT , bt_id INT , amount INT )
		RETURNS VOID
		STRICT VOLATILE
		SECURITY INVOKER
	AS $$
BEGIN
	LOOP
		UPDATE battles.buildings
			SET change = change + amount
			WHERE planet_id = pcr_id AND building_id = bt_id;
		EXIT WHEN FOUND;
		
		BEGIN
			INSERT INTO battles.buildings ( planet_id , building_id , change )
				VALUES ( pcr_id , bt_id , amount );
			EXIT;
		EXCEPTION
			WHEN unique_violation THEN
				-- Do nothing
		END;
	END LOOP;
END;
$$ LANGUAGE plpgsql;



--
-- Adds buildings to a planet's buildings list
--
-- Parameters:
--	p_id		Planet identifier
--	bt_id		Building type
--	amount		Amount of buildings to add
--	tick		Current tick identifier
--

CREATE OR REPLACE FUNCTION battles.add_buildings( p_id INT , bt_id INT , amount INT , tick BIGINT )
		RETURNS VOID
		STRICT VOLATILE
		SECURITY INVOKER
	AS $$
DECLARE
	b_id	BIGINT;
	pcr_id	BIGINT;
BEGIN
	-- Check building type
	PERFORM buildable_id FROM tech.buildings WHERE buildable_id = bt_id AND output_type = 'DEF';
	IF NOT FOUND THEN
		RETURN;
	END IF;

	-- Get battle identifier
	SELECT INTO b_id id FROM battles.battles
		WHERE location_id = p_id AND last_tick IS NULL;
	IF NOT FOUND THEN
		RETURN;
	END IF;

	-- Record changes
	pcr_id := battles.goc_planet( b_id , 'BUILD' , tick );
	PERFORM battles.record_building_change( pcr_id , bt_id , amount );
END;
$$ LANGUAGE plpgsql;



--
-- Removes buildings to a planet's buildings list
--
-- Parameters:
--	p_id		Planet identifier
--	bt_id		Building type
--	amount		Amount of buildings to remove
--	bdmg		Whether the losses have been caused by battle damage
--	tick		Current tick identifier
--

CREATE OR REPLACE FUNCTION battles.remove_buildings( p_id INT , bt_id INT , amount INT , bdmg BOOLEAN , tick BIGINT )
		RETURNS VOID
		STRICT VOLATILE
		SECURITY INVOKER
	AS $$
DECLARE
	b_id	BIGINT;
	pcr_id	BIGINT;
BEGIN
	-- Check building type
	PERFORM buildable_id FROM tech.buildings WHERE buildable_id = bt_id AND output_type = 'DEF';
	IF NOT FOUND THEN
		RETURN;
	END IF;

	-- Get battle identifier
	SELECT INTO b_id id FROM battles.battles
		WHERE location_id = p_id AND last_tick IS NULL;
	IF NOT FOUND THEN
		RETURN;
	END IF;

	-- Record changes
	pcr_id := battles.goc_planet( b_id , ( CASE WHEN bdmg THEN 'BATTLE' ELSE 'DESTROY' END )::battle_planet_change , tick );
	PERFORM battles.record_building_change( pcr_id , bt_id , -amount );
END;
$$ LANGUAGE plpgsql;



--
-- Adds a record when the planet is renamed
--
-- Parameters:
--	p_id		Planet identifier
--	nnm			New name
--

CREATE OR REPLACE FUNCTION battles.rename_planet( p_id INT , nnm TEXT )
		RETURNS VOID
		STRICT VOLATILE
		SECURITY INVOKER
	AS $$
DECLARE
	b_id	BIGINT;
	pcr_id	BIGINT;
BEGIN
	-- Get battle identifier
	SELECT INTO b_id id FROM battles.battles
		WHERE location_id = p_id AND last_tick IS NULL;
	IF NOT FOUND THEN
		RETURN;
	END IF;
	
	-- Record change
	pcr_id := battles.goc_planet( b_id , 'RENAME' , sys.get_tick() );
	UPDATE battles.planets
		SET name = nnm
		WHERE id = pcr_id;
END;
$$ LANGUAGE plpgsql;



--
-- Gets or creates a fleet change record
--
-- Parameters:
--	bp_id	Protagonist identifier
--	tick	Tick identifier
--	ctype	Change type
--

CREATE OR REPLACE FUNCTION battles.goc_fleet_change( bp_id BIGINT , tick BIGINT , ctype battle_fleet_change )
		RETURNS BIGINT
		STRICT VOLATILE
		SECURITY INVOKER
	AS $$
DECLARE
	bf_id	BIGINT;
BEGIN
	LOOP
		SELECT INTO bf_id id FROM battles.fleets
			WHERE protagonist_id = bp_id AND tick_identifier = tick AND change_type = ctype;
		EXIT WHEN FOUND;
		
		BEGIN
			INSERT INTO battles.fleets ( protagonist_id , tick_identifier , change_type )
				VALUES ( bp_id , tick , ctype )
				RETURNING id INTO bf_id;
			EXIT;
		EXCEPTION
			WHEN unique_violation THEN
				-- Do nothing
		END;
	END LOOP;
	RETURN bf_id;
END;
$$ LANGUAGE plpgsql;



--
-- Adds a fleet to the battle
--
-- Parameters:
--	b_id		Battle identifier
--	f_id		Fleet identifier
--	dep			Whether the fleet was added at the end of its deployment phase
--	tick		Current tick
--

CREATE OR REPLACE FUNCTION battles.add_fleet( b_id BIGINT , f_id BIGINT , dep BOOLEAN , tick BIGINT )
		RETURNS VOID
		STRICT VOLATILE
		SECURITY INVOKER
	AS $$
DECLARE
	e_id	INT;
	f_att	BOOLEAN;
	bp_id	BIGINT;
	bf_id	BIGINT;
	ctype	battle_fleet_change;
	rec		RECORD;
BEGIN
	-- Get owner's protagonist record
	SELECT INTO e_id , f_att owner_id , attacking
		FROM fleets.fleets
		WHERE id = f_id;
	bp_id := battles.goc_protagonist( b_id , e_id , f_att , tick );

	-- Try getting or creating the fleet's record
	ctype := ( CASE WHEN dep THEN 'BUILD' ELSE 'ARRIVE' END );
	bf_id := battles.goc_fleet_change( bp_id , tick , ctype );

	-- Insert or update fleet ships
	FOR rec IN SELECT ship_id , amount FROM fleets.ships WHERE fleet_id = f_id
	LOOP
		PERFORM battles.add_fleet_change( bf_id , rec.ship_id , rec.amount );
	END LOOP;
END;
$$ LANGUAGE plpgsql;



--
-- Removes a fleet from the battle
--
-- Parameters:
--	b_id		Battle identifier
--	f_id		Fleet identifier
--	ctype		Change type
--	tick		Current tick
--

CREATE OR REPLACE FUNCTION battles.remove_fleet( b_id BIGINT , f_id BIGINT , ctype battle_fleet_change , tick BIGINT )
		RETURNS VOID
		STRICT VOLATILE
		SECURITY INVOKER
	AS $$
DECLARE
	e_id	INT;
	f_att	BOOLEAN;
	bp_id	BIGINT;
	bf_id	BIGINT;
	rec		RECORD;
BEGIN
	-- Get owner's protagonist record
	SELECT INTO e_id , f_att owner_id , attacking
		FROM fleets.fleets
		WHERE id = f_id;
	bp_id := battles.goc_protagonist( b_id , e_id , f_att , tick );

	-- Try getting or creating the fleet's record
	bf_id := battles.goc_fleet_change( bp_id , tick , ctype );

	-- Insert or update fleet ships
	FOR rec IN SELECT ship_id , amount FROM fleets.ships WHERE fleet_id = f_id
	LOOP
		PERFORM battles.add_fleet_change( bf_id , rec.ship_id , - rec.amount );
	END LOOP;
END;
$$ LANGUAGE plpgsql;



--
-- Sets an empire's mode
--
-- Parameters:
--	b_id		Battle identifier
--	e_id		Empire identifier
--	att			Whether the empire is attacking or defending
--

CREATE OR REPLACE FUNCTION battles.set_mode( b_id BIGINT , e_id INT , att BOOLEAN )
		RETURNS VOID
		STRICT VOLATILE
		SECURITY INVOKER
	AS $$
DECLARE
	tick	BIGINT;
	p_id	BIGINT;
BEGIN
	SELECT INTO p_id p.id
		FROM battles.empires e
			INNER JOIN battles.protagonists p ON p.empire_id = e.id
		WHERE e.empire_id = e_id AND p.battle_id = b_id;
	IF NOT FOUND THEN
		RETURN;
	END IF;

	tick := sys.get_tick( );
	LOOP
		DELETE FROM battles.status_changes
			WHERE protagonist_id = p_id AND tick_identifier = tick AND attacking = ( NOT att );
		EXIT WHEN FOUND;
		
		BEGIN
			INSERT INTO battles.status_changes ( protagonist_id , tick_identifier , attacking )
				VALUES ( p_id , tick , att );
			EXIT;
		EXCEPTION
			WHEN unique_violation THEN
				-- Do nothing
		END;
		
		PERFORM * FROM battles.status_changes
			WHERE protagonist_id = p_id AND tick_identifier = tick AND attacking = att;
		EXIT WHEN FOUND;
	END LOOP;
END;
$$ LANGUAGE plpgsql;



--
-- Inflicts damage to one side of the engagement
--
-- Parameters:
--	b_id	Battle identifer
--	dmg		Amount of damage to inflict
--	att		Whether damage is being inflicted to attacking fleets
--	tick	Current tick identifier
--

CREATE OR REPLACE FUNCTION battles.inflict_damage( b_id BIGINT , dmg REAL , att BOOLEAN , tick BIGINT )
		RETURNS VOID
		STRICT VOLATILE
		SECURITY INVOKER
	AS $$
DECLARE
	planet			INT;
	tot_power		BIGINT;
	st_power		BIGINT;
	rec				RECORD;
BEGIN
	-- Get total power from fleets
	SELECT INTO tot_power sum( fs.power )
			FROM battles.battles b
				LEFT OUTER JOIN fleets.fleets f ON f.location_id = b.location_id AND f.attacking = att
				LEFT OUTER JOIN fleets.stats_view fs ON fs.id = f.id
				LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
			WHERE b.id = b_id AND m.fleet_id IS NULL;
	IF tot_power IS NULL THEN
		tot_power := 0;
	END IF;
	SELECT INTO planet location_id FROM battles.battles WHERE id = b_id;

	-- If damage is being inflicted to defence forces, handle defence buildings
	IF NOT att THEN
		st_power := battles.get_defence_power( b_id , tick );
		tot_power := tot_power + st_power;
		PERFORM sys.write_log( 'BattleUpdate' , 'TRACE'::log_level , 'About to inflict planet damage; total power: ' || tot_power
			|| '; planet power: ' || st_power || '; computed damage: ' || ( dmg * st_power / tot_power )::REAL );
		IF st_power <> 0 THEN
			PERFORM verse.inflict_battle_damage( planet , st_power , ( dmg * st_power / tot_power )::REAL , b_id , tick );
		END IF;
	END IF;
	
	-- Inflict damage to fleets
	FOR rec IN SELECT f.id , fs.power
				FROM battles.battles b
					INNER JOIN fleets.fleets f ON f.location_id = b.location_id
					INNER JOIN fleets.stats_view fs ON fs.id = f.id
					LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
				WHERE b.id = b_id AND m.fleet_id IS NULL AND f.attacking = att
	LOOP
		PERFORM fleets.inflict_battle_damage( rec.id , ( dmg * rec.power / tot_power )::REAL , b_id , tick );
	END LOOP;
END;
$$ LANGUAGE plpgsql;



--
-- Computes the size/power of a planet's defences at a given tick
--

CREATE TYPE planet_defence_size AS (
	item_id			INT ,
	amount			INT
);

CREATE OR REPLACE FUNCTION battles.get_defence_size( b_id BIGINT , tick BIGINT )
	RETURNS SETOF planet_defence_size
	STRICT STABLE
	SECURITY INVOKER
AS $$
	SELECT bb.building_id AS item_id , sum( bb.change )::INT AS amount
		FROM battles.planets bp
			INNER JOIN battles.buildings bb ON bb.planet_id = bp.id
		WHERE bp.battle_id = $1 AND bp.tick_identifier <= $2
		GROUP BY bb.building_id;
$$ LANGUAGE SQL;


CREATE OR REPLACE FUNCTION battles.set_defence_power( b_id BIGINT , tick BIGINT , pw BIGINT )
		RETURNS VOID
		STRICT VOLATILE
		SECURITY INVOKER
	AS $$
BEGIN
	IF battles.get_defence_power( b_id , tick ) <> pw
	THEN
		LOOP
			UPDATE battles.defences SET power = pw
				WHERE battle_id = b_id AND tick_identifier = tick;
			EXIT WHEN FOUND;
			
			BEGIN
				INSERT INTO battles.defences ( battle_id , tick_identifier , power )
					VALUES ( b_id , tick , pw );
				EXIT;
			EXCEPTION
				WHEN unique_violation THEN
					-- EMPTY
			END;
		END LOOP;
	END IF;
END;
$$ LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION battles.get_defence_power( b_id BIGINT , tick BIGINT )
	RETURNS BIGINT
	STRICT STABLE
	SECURITY DEFINER
AS $$
	SELECT power FROM battles.defences
		WHERE battle_id = $1 AND tick_identifier = (
				SELECT max( tick_identifier ) FROM battles.defences
					WHERE battle_id = $1 AND tick_identifier <= $2
			);
$$ LANGUAGE SQL;



--
-- Lists battle protagonists in a specific mode at a given tick
--

CREATE OR REPLACE FUNCTION battles.get_protagonists_with_mode( b_id BIGINT , tick BIGINT , mode BOOLEAN )
	RETURNS SETOF BIGINT
	STRICT STABLE
	SECURITY INVOKER
AS $$
	SELECT protagonist_id
		FROM battles.status_changes c
			INNER JOIN (
				SELECT sc.protagonist_id , max( sc.tick_identifier ) AS tick_identifier
					FROM battles.status_changes sc
						INNER JOIN battles.protagonists p ON p.id = sc.protagonist_id
					WHERE sc.tick_identifier <= $2 AND p.battle_id = $1
					GROUP BY protagonist_id
				) x USING ( protagonist_id , tick_identifier )
		WHERE c.attacking = $3;
$$ LANGUAGE SQL;



--
-- Computes the size/power of fleets in a specific mode at a given tick
--

CREATE TYPE battle_fleet_size AS (
	protagonist_id	BIGINT ,
	ship_id			INT ,
	amount			INT
);

CREATE OR REPLACE FUNCTION battles.get_fleets_composition( b_id BIGINT , tick BIGINT )
	RETURNS SETOF battle_fleet_size
	STRICT STABLE
	SECURITY INVOKER
AS $$
	SELECT bp.id AS protagonist_id , bs.ship_id AS item_id , sum( bs.change )::INT AS amount
		FROM battles.fleets bf
			INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
			INNER JOIN battles.ships bs ON bs.fleet_id = bf.id
		WHERE bp.battle_id = $1 AND bf.tick_identifier <= $2
		GROUP BY bp.id , bs.ship_id;
$$ LANGUAGE SQL;


CREATE TYPE battle_fleet_power AS (
	protagonist_id	BIGINT ,
	power			BIGINT
);


CREATE OR REPLACE FUNCTION battles.get_fleets_power( b_id BIGINT , tick BIGINT )
	RETURNS SETOF battle_fleet_power
	STRICT STABLE
	SECURITY INVOKER
AS $$
	SELECT ds.protagonist_id , ( CASE
				WHEN sum( ds.amount * s.power ) IS NULL THEN
					0
				ELSE
					sum( ds.amount * s.power )
			END ) AS power
		FROM battles.get_fleets_composition( $1 , $2 ) ds
			INNER JOIN tech.ships s ON s.buildable_id = ds.ship_id
		GROUP BY ds.protagonist_id;
$$ LANGUAGE SQL;


CREATE OR REPLACE FUNCTION battles.get_biggest_fleet_owner( b_id BIGINT , tick BIGINT )
	RETURNS INT
	STRICT STABLE
	SECURITY INVOKER
AS $$
	SELECT e.empire_id
		FROM battles.get_fleets_power( $1 , $2 ) fp
			INNER JOIN battles.protagonists bp ON bp.id = fp.protagonist_id
			INNER JOIN battles.empires e ON e.id = bp.empire_id
		ORDER BY fp.power DESC
		LIMIT 1;
$$ LANGUAGE SQL;


CREATE OR REPLACE FUNCTION battles.get_fleets_power( b_id BIGINT , tick BIGINT , mode BOOLEAN )
	RETURNS BIGINT
	STRICT STABLE
	SECURITY DEFINER
AS $$
	SELECT ( CASE
				WHEN sum( fp.power ) IS NULL THEN
					0
				ELSE
					sum( fp.power )
			END )::BIGINT
		FROM battles.get_fleets_power( $1 , $2 ) fp
			INNER JOIN battles.get_protagonists_with_mode( $1 , $2 , $3 ) pm
				ON fp.protagonist_id = pm;
$$ LANGUAGE SQL;