-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Views that are used to display battles
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------


--
-- Battle status view
--

CREATE VIEW battles.current_status
	AS SELECT location_id AS location , id , ( battles.get_defence_power( id , sys.get_tick() ) + battles.get_fleets_power( id , sys.get_tick() , FALSE ) ) AS defence ,
				battles.get_fleets_power( id , sys.get_tick() , TRUE ) AS attack
			FROM battles.battles WHERE last_tick IS NULL;

GRANT SELECT ON battles.current_status TO :dbuser;



--
-- Viewable battles, by empire
--

CREATE VIEW battles.empire_list_view
	AS SELECT be.empire_id AS empire , b.id AS battle ,
				bpt.id AS protagonist ,
				b.first_tick , b.last_tick ,
				p.name_id AS planet ,
				s.x , s.y , p.orbit ,
				bpl.name
			FROM battles.empires be
				INNER JOIN battles.protagonists bpt ON bpt.empire_id = be.id
				INNER JOIN battles.battles b ON b.id = bpt.battle_id
				INNER JOIN verse.planets p ON p.name_id = b.location_id
				INNER JOIN verse.systems s ON s.id = p.system_id
				INNER JOIN battles.planets bpl ON bpl.battle_id = b.id AND bpl.change_type = 'INIT'
			WHERE be.empire_id IS NOT NULL;

GRANT SELECT ON battles.empire_list_view TO :dbuser;


--
-- Ticks to include in a battle display
--

CREATE VIEW battles.battle_ticks_view
	AS SELECT x.battle , x.tick FROM (
				SELECT battle_id AS battle , tick_identifier AS tick
					FROM battles.planets
				UNION SELECT battle_id AS battle , tick_identifier AS tick
					FROM battles.defences
				UNION SELECT bp.battle_id AS battle , bsc.tick_identifier AS tick
					FROM battles.status_changes bsc
						INNER JOIN battles.protagonists bp ON bp.id = bsc.protagonist_id
				UNION SELECT bp.battle_id AS battle , bf.tick_identifier AS tick
					FROM battles.fleets bf
						INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
				UNION SELECT id AS battle , last_tick AS tick
					FROM battles.battles
					WHERE last_tick IS NOT NULL
			) x
		ORDER BY x.tick;

GRANT SELECT ON battles.battle_ticks_view TO :dbuser;



--
-- Mode history view
--

CREATE OR REPLACE FUNCTION battles.get_protagonist_status_at( bp_id BIGINT , tick_id BIGINT )
	RETURNS BOOLEAN
	STRICT IMMUTABLE
	SECURITY DEFINER
AS $$
	SELECT attacking FROM battles.status_changes
		WHERE protagonist_id = $1 AND tick_identifier <= $2
		ORDER BY tick_identifier DESC LIMIT 1;
$$ LANGUAGE SQL;

CREATE VIEW battles.mode_history_view
	AS SELECT btv.battle , btv.tick , bp.id AS protagonist ,
			be.id AS empire_id , be.name AS empire_name ,
			battles.get_protagonist_status_at( bp.id , btv.tick ) AS attacking
		FROM battles.battle_ticks_view btv
			INNER JOIN battles.protagonists bp ON bp.battle_id = btv.battle
			INNER JOIN battles.empires be ON be.id = bp.empire_id
		ORDER BY btv.tick , be.name;

GRANT SELECT ON battles.mode_history_view TO :dbuser;



--
-- Ships history
--

CREATE VIEW battles.protagonist_ships
	AS SELECT DISTINCT bf.protagonist_id , bs.ship_id
			FROM battles.fleets bf
				INNER JOIN battles.ships bs ON bs.fleet_id = bf.id;

CREATE OR REPLACE FUNCTION battles.get_lost_ships( bp_id BIGINT , tick_id BIGINT, ship_id INT )
	RETURNS BIGINT
	STRICT IMMUTABLE
	SECURITY DEFINER
AS $$
	SELECT -sum( fs.change )
		FROM battles.ships fs
			INNER JOIN battles.fleets bf ON fs.fleet_id = bf.id
		WHERE bf.protagonist_id = $1 AND bf.tick_identifier <= $2
			AND bf.change_type = 'BATTLE' AND fs.ship_id = $3
$$ LANGUAGE SQL;


CREATE OR REPLACE FUNCTION battles.get_current_ships( bp_id BIGINT , tick_id BIGINT, ship_id INT )
	RETURNS BIGINT
	STRICT IMMUTABLE
	SECURITY DEFINER
AS $$
	SELECT sum( fs.change )
		FROM battles.ships fs
			INNER JOIN battles.fleets bf ON fs.fleet_id = bf.id
		WHERE bf.protagonist_id = $1 AND bf.tick_identifier <= $2
			AND fs.ship_id = $3
$$ LANGUAGE SQL;


CREATE VIEW battles.fleets_history
	AS SELECT elv.empire , elv.battle , btv.tick ,
			bpt.id AS protagonist , t.translated_string AS ship_type ,
			battles.get_current_ships( bpt.id , btv.tick , bps.ship_id ) AS current ,
			battles.get_lost_ships( bpt.id , btv.tick , bps.ship_id ) AS lost ,
			s.power AS ship_power
		FROM battles.empire_list_view elv
			INNER JOIN battles.battle_ticks_view btv USING (battle)
			INNER JOIN battles.protagonists bpt ON bpt.battle_id = elv.battle
			INNER JOIN battles.protagonist_ships bps ON bps.protagonist_id = bpt.id
			INNER JOIN tech.ships s ON s.buildable_id = bps.ship_id
			INNER JOIN naming.empire_names en ON en.id = elv.empire
			INNER JOIN users.credentials c ON c.address_id = en.owner_id
			INNER JOIN defs.translations t
				ON t.lang_id = c.language_id AND t.string_id = bps.ship_id
		ORDER BY s.power;

GRANT SELECT ON battles.fleets_history TO :dbuser;



--
-- Protagonist presence in a battle at any given tick
--

CREATE VIEW battles.protagonist_ship_types
	AS SELECT DISTINCT bp.id AS protagonist , bs.ship_id AS ship_type
		FROM battles.protagonists bp
			INNER JOIN battles.fleets bf ON bf.protagonist_id = bp.id
			INNER JOIN battles.ships bs ON bs.fleet_id = bf.id;

CREATE VIEW battles.ships_at_tick
	AS SELECT btv.battle , btv.tick , bp.id AS protagonist ,
				sum( battles.get_current_ships( bp.id , btv.tick, bs.ship_type ) ) AS ships
			FROM battles.battle_ticks_view btv
				INNER JOIN battles.protagonists bp ON bp.battle_id = btv.battle
				INNER JOIN battles.protagonist_ship_types bs ON bs.protagonist = bp.id
			GROUP BY btv.battle , btv.tick , bp.id;

CREATE OR REPLACE FUNCTION battles.get_current_ships( bp_id BIGINT , tick_id BIGINT )
        RETURNS BIGINT
        STRICT IMMUTABLE
        SECURITY DEFINER
AS $$
        SELECT ( CASE WHEN sum( fs.change ) IS NULL THEN 0 ELSE sum( fs.change ) END )
                FROM battles.ships fs
                        INNER JOIN battles.fleets bf ON fs.fleet_id = bf.id
                WHERE bf.protagonist_id = $1 AND bf.tick_identifier <= $2
$$ LANGUAGE SQL;


CREATE VIEW battles.protagonist_presence
        AS SELECT btv.battle , btv.tick , bp.id AS protagonist ,
                                ( bpo.protagonist_id IS NOT NULL
                                        OR battles.get_current_ships( bp.id , btv.tick ) > 0 ) AS present ,
                                ( bpo.protagonist_id IS NOT NULL ) AS planet_owner
                        FROM battles.battle_ticks_view btv
                                INNER JOIN battles.protagonists bp ON bp.battle_id = btv.battle
                                LEFT OUTER JOIN battles.planet_ownership bpo
                                        ON bpo.protagonist_id = bp.id AND ( bpo.abandoned_at IS NULL OR bpo.abandoned_at > btv.tick );

GRANT SELECT ON battles.protagonist_presence TO :dbuser;


--
-- Buildings history
--


CREATE VIEW battles.buildings_list
	AS SELECT DISTINCT bp.battle_id AS battle , bb.building_id
		FROM battles.planets bp
			INNER JOIN battles.buildings bb ON bb.planet_id = bp.id;


CREATE OR REPLACE FUNCTION battles.get_current_buildings( b_id BIGINT , tick_id BIGINT , building_id INT )
	RETURNS BIGINT
	STRICT IMMUTABLE
	SECURITY DEFINER
AS $$
	SELECT sum( change )
		FROM battles.buildings b
			INNER JOIN battles.planets bp ON bp.id = b.planet_id
		WHERE bp.battle_id = $1 AND bp.tick_identifier <= $2 AND b.building_id = $3;
$$ LANGUAGE SQL;


CREATE OR REPLACE FUNCTION battles.get_lost_buildings( b_id BIGINT , tick_id BIGINT , building_id INT )
	RETURNS BIGINT
	STRICT IMMUTABLE
	SECURITY DEFINER
AS $$
	SELECT -sum( change )
		FROM battles.buildings b
			INNER JOIN battles.planets bp ON bp.id = b.planet_id
		WHERE bp.battle_id = $1 AND bp.tick_identifier <= $2
			AND b.building_id = $3 AND bp.change_type = 'BATTLE';
$$ LANGUAGE SQL;


CREATE VIEW battles.raw_buildings_history
	AS SELECT btv.battle , btv.tick , bbl.building_id ,
				battles.get_current_buildings( btv.battle , btv.tick , bbl.building_id ) AS current ,
				battles.get_lost_buildings( btv.battle , btv.tick , bbl.building_id ) AS lost ,
				b.output AS raw_power
			FROM battles.battle_ticks_view btv
				INNER JOIN battles.buildings_list bbl USING (battle)
				INNER JOIN tech.buildings b ON b.buildable_id = bbl.building_id;

CREATE VIEW battles.raw_buildings_power
	AS SELECT rbh.battle , rbh.tick ,
			sum( rbh.current * rbh.raw_power ) AS raw_power ,
			battles.get_defence_power( rbh.battle , rbh.tick ) AS actual_power
		FROM battles.raw_buildings_history rbh
		GROUP BY rbh.battle , rbh.tick;


CREATE VIEW battles.buildings_history
	AS SELECT elv.empire , rbh.battle , rbh.tick ,
				t.translated_string AS building ,
				( CASE WHEN rbh.current IS NULL THEN 0 ELSE rbh.current END ) AS current ,
				( CASE WHEN rbh.lost IS NULL THEN 0 ELSE rbh.lost END ) AS lost ,
				( CASE
					WHEN rbp.raw_power = 0 THEN
						rbh.raw_power
					ELSE
						rbh.raw_power::REAL * rbp.actual_power::REAL / rbp.raw_power::REAL
				END )::REAL AS power
			FROM battles.empire_list_view elv
				INNER JOIN battles.raw_buildings_history rbh USING (battle)
				INNER JOIN battles.raw_buildings_power rbp USING (battle,tick)
				INNER JOIN naming.empire_names en ON en.id = elv.empire
				INNER JOIN users.credentials c ON c.address_id = en.owner_id
				INNER JOIN defs.translations t
					ON t.string_id = rbh.building_id AND t.lang_id = c.language_id
			ORDER BY rbp.raw_power;

GRANT SELECT ON battles.buildings_history TO :dbuser;



--
-- Events
--

CREATE VIEW battles.rename_events
	AS SELECT bp.battle_id AS battle , bp.tick_identifier AS tick ,
				'RENAME'::TEXT AS event_type , TRUE AS is_planet ,
				NULL::BIGINT AS event_id , bp.name AS name , NULL::BOOLEAN AS attack
			FROM battles.planets bp
			WHERE bp.change_type = 'RENAME';

CREATE VIEW battles.switch_events
	AS SELECT bp.battle_id AS battle , bsc.tick_identifier AS tick ,
				'SWITCH'::TEXT AS event_type , FALSE AS is_planet ,
				NULL::BIGINT AS event_id , be.name AS name , bsc.attacking AS attack
			FROM battles.status_changes bsc
				INNER JOIN battles.protagonists bp ON bp.id = bsc.protagonist_id
				INNER JOIN battles.empires be ON be.id = bp.empire_id
				INNER JOIN battles.battles b
					ON b.id = bp.battle_id AND bsc.tick_identifier > b.first_tick;

CREATE VIEW battles.arrive_events
	AS SELECT bp.battle_id AS battle , bf.tick_identifier AS tick ,
				'ARRIVE'::TEXT AS event_type , FALSE AS is_planet ,
				bf.id AS event_id , be.name AS name ,
				battles.get_protagonist_status_at( bp.id , bf.tick_identifier ) AS attack
			FROM battles.fleets bf
				INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
				INNER JOIN battles.empires be ON be.id = bp.empire_id
			WHERE bf.change_type = 'ARRIVE';

CREATE VIEW battles.depart_events
	AS SELECT bp.battle_id AS battle , bf.tick_identifier AS tick ,
				'DEPART'::TEXT AS event_type , FALSE AS is_planet ,
				bf.id AS event_id , be.name AS name ,
				battles.get_protagonist_status_at( bp.id , bf.tick_identifier ) AS attack
			FROM battles.fleets bf
				INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
				INNER JOIN battles.empires be ON be.id = bp.empire_id
			WHERE bf.change_type = 'DEPART';

CREATE VIEW battles.fleet_destroy_events
	AS SELECT bp.battle_id AS battle , bf.tick_identifier AS tick ,
				'DESTROY'::TEXT AS event_type , FALSE AS is_planet ,
				bf.id AS event_id , be.name AS name ,
				battles.get_protagonist_status_at( bp.id , bf.tick_identifier ) AS attack
			FROM battles.fleets bf
				INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
				INNER JOIN battles.empires be ON be.id = bp.empire_id
			WHERE bf.change_type = 'DISBAND';

CREATE VIEW battles.fleet_build_events
	AS SELECT bp.battle_id AS battle , bf.tick_identifier AS tick ,
				'BUILD'::TEXT AS event_type , FALSE AS is_planet ,
				bf.id AS event_id , be.name AS name ,
				battles.get_protagonist_status_at( bp.id , bf.tick_identifier ) AS attack
			FROM battles.fleets bf
				INNER JOIN battles.protagonists bp ON bp.id = bf.protagonist_id
				INNER JOIN battles.empires be ON be.id = bp.empire_id
			WHERE bf.change_type = 'BUILD';

CREATE VIEW battles.bld_destroy_events
	AS SELECT bp.battle_id AS battle , bp.tick_identifier AS tick ,
				'DESTROY'::TEXT AS event_type , TRUE AS is_planet ,
				bp.id AS event_id , NULL::TEXT AS name , FALSE AS attack
			FROM battles.planets bp
			WHERE bp.change_type = 'DESTROY';

CREATE VIEW battles.bld_build_events
	AS SELECT bp.battle_id AS battle , bp.tick_identifier AS tick ,
				'BUILD'::TEXT AS event_type , TRUE AS is_planet ,
				bp.id AS event_id , NULL::TEXT AS name , FALSE AS attack
			FROM battles.planets bp
			WHERE bp.change_type = 'BUILD';

			
CREATE VIEW battles.events_history
	AS SELECT x.* FROM (
				SELECT * FROM battles.rename_events
				UNION ALL SELECT * FROM battles.switch_events
				UNION ALL SELECT * FROM battles.arrive_events
				UNION ALL SELECT * FROM battles.depart_events
				UNION ALL SELECT * FROM battles.fleet_destroy_events
				UNION ALL SELECT * FROM battles.fleet_build_events
				UNION ALL SELECT * FROM battles.bld_destroy_events
				UNION ALL SELECT * FROM battles.bld_build_events
			) x
		ORDER BY x.tick DESC , x.is_planet DESC , x.event_type , x.attack , x.name;

GRANT SELECT ON battles.events_history TO :dbuser;


--
-- Ships/buildings for events
--

CREATE VIEW battles.planet_event_items
	AS SELECT elv.empire AS empire , TRUE AS is_planet , bp.id AS event_id ,
				bp.battle_id AS battle , bp.tick_identifier AS tick ,
				t.translated_string AS nature , abs( bb.change ) AS amount ,
				b.output AS power
			FROM battles.empire_list_view elv
				INNER JOIN battles.planets bp ON bp.battle_id = elv.battle
				INNER JOIN battles.buildings bb ON bb.planet_id = bp.id
				INNER JOIN naming.empire_names en ON en.id = elv.empire
				INNER JOIN users.credentials c ON c.address_id = en.owner_id
				INNER JOIN defs.translations t
					ON t.lang_id = c.language_id AND t.string_id = bb.building_id
				INNER JOIN tech.buildings b ON b.buildable_id = bb.building_id
			WHERE bp.change_type NOT IN ( 'INIT', 'BATTLE' );

CREATE VIEW battles.fleet_event_items
	AS SELECT elv.empire AS empire , FALSE AS is_planet , bf.id AS event_id ,
				bp.battle_id AS battle , bf.tick_identifier AS tick ,
				t.translated_string AS nature , abs( bs.change ) AS amount ,
				s.power AS power
			FROM battles.empire_list_view elv
				INNER JOIN battles.protagonists bp ON bp.battle_id = elv.battle
				INNER JOIN battles.fleets bf ON bf.protagonist_id = bp.id
				INNER JOIN battles.ships bs ON bs.fleet_id = bf.id
				INNER JOIN naming.empire_names en ON en.id = elv.empire
				INNER JOIN users.credentials c ON c.address_id = en.owner_id
				INNER JOIN defs.translations t
					ON t.lang_id = c.language_id AND t.string_id = bs.ship_id
				INNER JOIN tech.ships s ON s.buildable_id = bs.ship_id
			WHERE bf.change_type NOT IN ( 'INIT', 'BATTLE' );

CREATE VIEW battles.event_items
	AS SELECT x.* FROM (
				SELECT * FROM battles.planet_event_items
				UNION ALL SELECT * FROM battles.fleet_event_items
			) x
		ORDER BY x.power;

GRANT SELECT ON battles.event_items TO :dbuser;



--
-- Battles list
--

CREATE VIEW battles.last_presence
		AS SELECT protagonist , max( tick ) AS last_present
			FROM battles.protagonist_presence
			WHERE present
			GROUP BY protagonist;

CREATE VIEW battles.first_presence
		AS SELECT protagonist , min( tick ) AS first_present
			FROM battles.protagonist_presence
			WHERE present
			GROUP BY protagonist;

CREATE VIEW battles.last_update
		AS SELECT p.id AS protagonist , max( u.tick ) AS last_update
			FROM battles.protagonists p
				INNER JOIN battles.battle_ticks_view u ON u.battle = p.battle_id
			GROUP BY p.id;

CREATE VIEW battles.full_battles_list
        AS SELECT elv.empire , elv.battle , elv.planet , elv.x , elv.y , elv.orbit , elv.name ,
                                fp.first_present AS first_tick , ( CASE
                                        WHEN elv.last_tick IS NOT NULL THEN
                                                lp.last_present
                                        WHEN lp.last_present = lu.last_update THEN
                                                NULL
                                        ELSE
                                                lp.last_present
                                END )::BIGINT AS last_tick , lu.last_update ,
                                ( elv.last_tick IS NOT NULL ) AS finished
                        FROM battles.empire_list_view elv
                                INNER JOIN battles.first_presence fp USING (protagonist)
                                INNER JOIN battles.last_presence lp USING (protagonist)
                                INNER JOIN battles.last_update lu USING (protagonist);

CREATE TABLE battles.finished_battles_list(
  empire                INT NOT NULL ,
  battle                BIGINT NOT NULL ,
  planet                INT NOT NULL ,
  x                     INT NOT NULL ,
  y                     INT NOT NULL ,
  orbit                 INT NOT NULL ,
  name                  VARCHAR( 20 ) NOT NULL ,
  first_tick            BIGINT ,
  last_tick             BIGINT ,
  last_update           BIGINT ,
  PRIMARY KEY( empire , battle )
);

CREATE VIEW battles.current_battles_list
        AS SELECT elv.empire , elv.battle , elv.planet , elv.x , elv.y , elv.orbit , elv.name ,
                                fp.first_present AS first_tick , ( CASE
                                        WHEN lp.last_present = lu.last_update THEN
                                                NULL
                                        ELSE
                                                lp.last_present
                                END )::BIGINT AS last_tick , lu.last_update
                        FROM battles.empire_list_view elv
                                INNER JOIN battles.first_presence fp USING (protagonist)
                                INNER JOIN battles.last_presence lp USING (protagonist)
                                INNER JOIN battles.last_update lu USING (protagonist)
                        WHERE elv.last_tick IS NULL;


CREATE VIEW battles.battles_list
	AS SELECT fbl.* , TRUE AS finished FROM battles.finished_battles_list fbl
          UNION ALL SELECT cbl.* , FALSE AS finished FROM battles.current_battles_list cbl;

GRANT SELECT ON battles.battles_list TO :dbuser;