1497 lines
44 KiB
MySQL
1497 lines
44 KiB
MySQL
|
-- LegacyWorlds Beta 6
|
||
|
-- PostgreSQL database scripts
|
||
|
--
|
||
|
-- Fleets views and management functions
|
||
|
--
|
||
|
-- Copyright(C) 2004-2010, DeepClone Development
|
||
|
-- --------------------------------------------------------
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Merges two fleets' ships into the first fleet
|
||
|
-- /!\ The second fleet is *not* deleted. /!\
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- mt_id Merge target identifier
|
||
|
-- ms_id Merge source identifier
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.merge_ships( mt_id BIGINT , ms_id BIGINT )
|
||
|
RETURNS VOID
|
||
|
STRICT VOLATILE
|
||
|
SECURITY INVOKER
|
||
|
AS $$
|
||
|
BEGIN
|
||
|
CREATE TEMPORARY TABLE flt_merge( LIKE fleets.ships );
|
||
|
|
||
|
INSERT INTO flt_merge (fleet_id , ship_id , amount , damage )
|
||
|
SELECT mt_id , s.ship_id , sum( s.amount ) , sum( s.damage )
|
||
|
FROM fleets.ships s
|
||
|
WHERE s.fleet_id IN ( mt_id , ms_id )
|
||
|
GROUP BY s.ship_id;
|
||
|
|
||
|
DELETE FROM fleets.ships WHERE fleet_id = mt_id;
|
||
|
INSERT INTO fleets.ships SELECT * FROM flt_merge;
|
||
|
|
||
|
DROP TABLE flt_merge;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Compute duration of in-system movement
|
||
|
--
|
||
|
-- Source and destination "orbits" are actually real numbers, which indicate a fleet's
|
||
|
-- current location. Orbit 5.5 is the system's outer limit, therefore the range for
|
||
|
-- these numbers is [1;5.5].
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- f_time Fleet flight time
|
||
|
-- s_orbit Source orbit
|
||
|
-- d_orbit Destination orbit
|
||
|
--
|
||
|
-- Returns:
|
||
|
-- the in-system movement's duration
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.compute_insystem_duration( f_time INT , s_orbit REAL , d_orbit REAL )
|
||
|
RETURNS INT
|
||
|
STRICT IMMUTABLE
|
||
|
SECURITY INVOKER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
tm INT;
|
||
|
BEGIN
|
||
|
tm := round( abs( s_orbit - d_orbit ) * 2.0 * f_time );
|
||
|
RETURN ( CASE WHEN tm = 0 THEN 1 ELSE tm END );
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Compute duration of outer space movement
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- f_time Fleet flight time
|
||
|
-- s_x Source X coordinate
|
||
|
-- s_y Source Y coordinate
|
||
|
-- d_x Destination X coordinate
|
||
|
-- d_y Destination Y coordinate
|
||
|
--
|
||
|
-- Returns:
|
||
|
-- the outer space movement's duration
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.compute_outerspace_duration( f_time INT , s_x REAL , s_y REAL , d_x REAL , d_y REAL )
|
||
|
RETURNS INT
|
||
|
STRICT IMMUTABLE
|
||
|
SECURITY INVOKER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
tm INT;
|
||
|
BEGIN
|
||
|
tm := round( sqrt( ( s_x - d_x ) ^ 2 + ( s_y - d_y ) ^ 2 ) * f_time * 15.0 );
|
||
|
RETURN ( CASE WHEN tm = 0 THEN 1 ELSE tm END );
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Compute the current orbit of a fleet flying in a system
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- f_time Fleet flight time
|
||
|
-- rp_orbit Orbit of the reference point
|
||
|
-- outwards Whether the fleet is moving outwards or inwards
|
||
|
-- past_rp Whether the fleet has passed the reference point or not
|
||
|
-- ft_left Remaining flight time
|
||
|
--
|
||
|
-- Returns;
|
||
|
-- The real number indicating the fleet's position
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.compute_current_orbit(
|
||
|
f_time INT , rp_orbit INT , outwards BOOLEAN , past_rp BOOLEAN , ft_left INT )
|
||
|
RETURNS REAL
|
||
|
STRICT IMMUTABLE
|
||
|
SECURITY INVOKER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
dist REAL;
|
||
|
dir REAL;
|
||
|
rloc REAL;
|
||
|
BEGIN
|
||
|
dist := 1.0 - ft_left::REAL / f_time::REAL;
|
||
|
dir := ( CASE WHEN outwards THEN 0.5 ELSE -0.5 END );
|
||
|
IF past_rp THEN
|
||
|
rloc := rp_orbit;
|
||
|
ELSEIF outwards THEN
|
||
|
rloc := rp_orbit - 0.5;
|
||
|
ELSE
|
||
|
rloc := rp_orbit + 0.5;
|
||
|
END IF;
|
||
|
RETURN rloc + dir * dist;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Compute the current coordinates of a fleet flying in outer space
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- f_time Fleet flight time
|
||
|
-- s_x Source X coordinate
|
||
|
-- s_y Source Y coordinate
|
||
|
-- d_x Destination X coordinate
|
||
|
-- d_y Destination Y coordinate
|
||
|
-- r_time Remaining flight time
|
||
|
--
|
||
|
-- Returns:
|
||
|
-- c_x Current X coordinate
|
||
|
-- c_y Current Y coordinate
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.compute_current_location(
|
||
|
f_time INT , s_x REAL , s_y REAL , d_x REAL , d_y REAL , r_time INT ,
|
||
|
OUT c_x REAL , OUT c_y REAL )
|
||
|
STRICT IMMUTABLE
|
||
|
SECURITY INVOKER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
tot_time REAL;
|
||
|
BEGIN
|
||
|
tot_time := fleets.compute_outerspace_duration( f_time , s_x , s_y , d_x , d_y );
|
||
|
c_x := s_x + ( d_x - s_x ) * ( 1 - r_time / tot_time );
|
||
|
c_y := s_y + ( d_y - s_y ) * ( 1 - r_time / tot_time );
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Compute the duration and direction for a planet-to-planet flight
|
||
|
--
|
||
|
-- /!\ Marked as immutable, but does in fact query the DB. Planets don't move around.
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- f_time Fleet flight time
|
||
|
-- s_id Source planet identifier
|
||
|
-- d_id Destination planet identifier
|
||
|
--
|
||
|
-- Returns:
|
||
|
-- duration Flight duration
|
||
|
-- direction Whether the fleet is moving inwards (FALSE) or outwards (TRUE)
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.compute_flight_init(
|
||
|
f_time INT , s_id INT , d_id INT ,
|
||
|
OUT duration INT , OUT direction BOOLEAN )
|
||
|
STRICT IMMUTABLE
|
||
|
SECURITY INVOKER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
s_rec RECORD;
|
||
|
d_rec RECORD;
|
||
|
BEGIN
|
||
|
IF s_id = d_id THEN
|
||
|
RETURN;
|
||
|
END IF;
|
||
|
|
||
|
-- Get source planet coordinates, orbit and system ID
|
||
|
SELECT INTO s_rec s.x AS x , s.y AS y , p.orbit AS orbit , s.id AS sid
|
||
|
FROM verse.planets p
|
||
|
INNER JOIN verse.systems s ON s.id = p.system_id
|
||
|
WHERE p.name_id = s_id;
|
||
|
|
||
|
-- Get destination planet coordinates, orbit and system ID
|
||
|
SELECT INTO d_rec s.x AS x , s.y AS y , p.orbit AS orbit , s.id AS sid
|
||
|
FROM verse.planets p
|
||
|
INNER JOIN verse.systems s ON s.id = p.system_id
|
||
|
WHERE p.name_id = d_id;
|
||
|
|
||
|
IF s_rec.sid = d_rec.sid THEN
|
||
|
-- Movement in the same system
|
||
|
duration := fleets.compute_insystem_duration( f_time , s_rec.orbit , d_rec.orbit );
|
||
|
direction := ( d_rec.orbit > s_rec.orbit );
|
||
|
ELSE
|
||
|
-- Movement to another system
|
||
|
duration := fleets.compute_insystem_duration( f_time , s_rec.orbit , 5.5 )
|
||
|
+ fleets.compute_insystem_duration( f_time , d_rec.orbit , 5.5 )
|
||
|
+ fleets.compute_outerspace_duration( f_time , s_rec.x , s_rec.y , d_rec.x , d_rec.y );
|
||
|
direction := TRUE;
|
||
|
END IF;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Compute a flight's duration from an in-system redirection
|
||
|
--
|
||
|
-- /!\ Marked as immutable, but does in fact query the DB. Planets don't move around.
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- f_time Fleet flight time
|
||
|
-- s_sys Source system
|
||
|
-- s_orbit Source "orbit" as a real number
|
||
|
-- d_id Destination planet
|
||
|
--
|
||
|
-- Returns:
|
||
|
-- duration Flight duration
|
||
|
-- direction Whether the fleet is moving inwards (FALSE) or outwards (TRUE)
|
||
|
-- s_duration State duration
|
||
|
-- ref_point Reference point
|
||
|
-- past_rp Whether the fleet has passed the reference point or is moving
|
||
|
-- towards it
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.compute_insystem_redirect(
|
||
|
f_time INT , s_sys INT , s_orbit REAL , d_id INT ,
|
||
|
OUT duration INT , OUT direction BOOLEAN , OUT s_duration INT ,
|
||
|
OUT ref_point INT , OUT past_rp BOOLEAN )
|
||
|
STRICT IMMUTABLE
|
||
|
SECURITY INVOKER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
s_rec RECORD;
|
||
|
d_rec RECORD;
|
||
|
torb REAL;
|
||
|
rporb INT;
|
||
|
BEGIN
|
||
|
-- Get destination planet coordinates, orbit and system ID
|
||
|
SELECT INTO d_rec s.x AS x , s.y AS y , p.orbit AS orbit , s.id AS sid
|
||
|
FROM verse.planets p
|
||
|
INNER JOIN verse.systems s ON s.id = p.system_id
|
||
|
WHERE p.name_id = d_id;
|
||
|
|
||
|
IF d_rec.sid = s_sys THEN
|
||
|
-- Movement in the same system
|
||
|
duration := fleets.compute_insystem_duration( f_time , s_orbit , d_rec.orbit );
|
||
|
direction := ( d_rec.orbit > s_orbit );
|
||
|
ELSE
|
||
|
-- Movement to another system
|
||
|
SELECT INTO s_rec x , y FROM verse.systems WHERE id = s_sys;
|
||
|
duration := fleets.compute_insystem_duration( f_time , s_orbit , 5.5 )
|
||
|
+ fleets.compute_insystem_duration( f_time , d_rec.orbit , 5.5 )
|
||
|
+ fleets.compute_outerspace_duration( f_time , s_rec.x , s_rec.y , d_rec.x , d_rec.y );
|
||
|
direction := TRUE;
|
||
|
END IF;
|
||
|
|
||
|
-- Compute state duration and reference point
|
||
|
IF s_orbit::NUMERIC % 0.5 = 0 THEN
|
||
|
s_duration := f_time;
|
||
|
past_rp := ( s_orbit::NUMERIC % 1 = 0);
|
||
|
rporb := ( CASE WHEN direction THEN ceil( s_orbit ) ELSE floor( s_orbit ) END );
|
||
|
ELSE
|
||
|
torb := s_orbit * 2;
|
||
|
IF direction THEN
|
||
|
torb := ceil( torb );
|
||
|
ELSE
|
||
|
torb := floor( torb );
|
||
|
END IF;
|
||
|
s_duration := fleets.compute_insystem_duration( f_time , s_orbit , ( torb / 2 )::REAL );
|
||
|
rporb := round( s_orbit );
|
||
|
past_rp := ( CASE WHEN direction THEN ( rporb::REAL <= s_orbit ) ELSE ( rporb::REAL >= s_orbit ) END );
|
||
|
END IF;
|
||
|
SELECT INTO ref_point name_id FROM verse.planets p
|
||
|
WHERE p.system_id = s_sys AND orbit = rporb;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Compute a flight's duration from an outer space redirection
|
||
|
--
|
||
|
-- /!\ Marked as immutable, but does in fact query the DB. Planets don't move around.
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- f_time Fleet flight time
|
||
|
-- s_x Source X coordinate
|
||
|
-- s_y Source Y coordinate
|
||
|
-- d_id Destination planet
|
||
|
--
|
||
|
-- Returns:
|
||
|
-- duration Flight duration
|
||
|
-- s_duration State duration
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.compute_outerspace_redirect(
|
||
|
f_time INT , s_x REAL , s_y REAL , d_id INT ,
|
||
|
OUT duration INT , OUT s_duration INT )
|
||
|
STRICT IMMUTABLE
|
||
|
SECURITY INVOKER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
s_rec RECORD;
|
||
|
d_rec RECORD;
|
||
|
BEGIN
|
||
|
-- Get destination planet coordinates, orbit and system ID
|
||
|
SELECT INTO d_rec s.x AS x , s.y AS y , p.orbit AS orbit , s.id AS sid
|
||
|
FROM verse.planets p
|
||
|
INNER JOIN verse.systems s ON s.id = p.system_id
|
||
|
WHERE p.name_id = d_id;
|
||
|
|
||
|
s_duration := fleets.compute_outerspace_duration( f_time , s_x , s_y , d_rec.x , d_rec.y );
|
||
|
duration := fleets.compute_insystem_duration( f_time , d_rec.orbit , 5.5 ) + s_duration;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Give movement orders to a set of fleets
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- emp_id Expected owner identifier
|
||
|
-- fleet_ids Array of fleet identifiers
|
||
|
-- dest_id Destination planet
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.set_movement_orders( emp_id INT , fleet_ids BIGINT[] , dest_id INT )
|
||
|
RETURNS VOID
|
||
|
STRICT VOLATILE
|
||
|
SECURITY INVOKER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
rec RECORD;
|
||
|
dur INT;
|
||
|
s_dur INT;
|
||
|
dir BOOLEAN;
|
||
|
rpid INT;
|
||
|
prp BOOLEAN;
|
||
|
cx REAL;
|
||
|
cy REAL;
|
||
|
BEGIN
|
||
|
-- Lock fleets and planets
|
||
|
PERFORM * FROM fleets.fleets f
|
||
|
INNER JOIN emp.empires e ON e.name_id = f.owner_id
|
||
|
INNER JOIN verse.planets p ON f.location_id = p.name_id
|
||
|
WHERE f.id = ANY( fleet_ids ) AND f.status = 'AVAILABLE'
|
||
|
AND e.name_id = emp_id AND f.location_id <> dest_id
|
||
|
FOR UPDATE OF p , f;
|
||
|
|
||
|
FOR rec IN SELECT f.id AS id , f.location_id AS location ,
|
||
|
fs.flight_time AS flight_time , b.id AS battle ,
|
||
|
p.orbit AS orbit , s.x AS x , s.y AS y ,
|
||
|
m.time_left AS mv_time , m.state_time_left AS mv_state_time ,
|
||
|
osms.start_x AS os_start_x , osms.start_y AS os_start_y ,
|
||
|
isms.ref_point_id AS is_ref_point , isms.outwards AS is_outwards ,
|
||
|
isms.past_ref_point AS is_past_ref_point ,
|
||
|
rp.system_id AS is_ref_point_system , rp.orbit AS is_ref_point_orbit
|
||
|
FROM fleets.fleets f
|
||
|
INNER JOIN emp.empires e ON e.name_id = f.owner_id
|
||
|
INNER JOIN verse.planets p ON f.location_id = p.name_id
|
||
|
INNER JOIN verse.systems s ON s.id = p.system_id
|
||
|
INNER JOIN fleets.stats_view fs ON fs.id = f.id
|
||
|
LEFT OUTER JOIN battles.battles b
|
||
|
ON b.location_id = f.location_id AND b.last_tick IS NULL
|
||
|
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
|
||
|
LEFT OUTER JOIN fleets.ms_space osms ON osms.movement_id = f.id
|
||
|
LEFT OUTER JOIN fleets.ms_system isms ON isms.movement_id = f.id
|
||
|
LEFT OUTER JOIN verse.planets rp ON isms.ref_point_id = rp.name_id
|
||
|
WHERE f.id = ANY( fleet_ids ) AND f.status = 'AVAILABLE'
|
||
|
AND e.name_id = emp_id AND f.location_id <> dest_id
|
||
|
LOOP
|
||
|
IF rec.mv_time IS NULL THEN
|
||
|
-- New fleet movement
|
||
|
SELECT INTO dur, dir duration , direction
|
||
|
FROM fleets.compute_flight_init( rec.flight_time , rec.location , dest_id );
|
||
|
INSERT INTO fleets.movements ( fleet_id , source_id, time_left , state_time_left )
|
||
|
VALUES ( rec.id , rec.location , dur , rec.flight_time );
|
||
|
INSERT INTO fleets.ms_system( movement_id , ref_point_id , outwards , past_ref_point )
|
||
|
VALUES ( rec.id , rec.location , dir , TRUE );
|
||
|
UPDATE fleets.fleets SET location_id = dest_id
|
||
|
WHERE id = rec.id;
|
||
|
|
||
|
-- Remove fleet from battle (if there is one)
|
||
|
PERFORM battles.remove_fleet( rec.battle , rec.id , 'DEPART'::battle_fleet_change , sys.get_tick() );
|
||
|
ELSE
|
||
|
-- Fleet redirection
|
||
|
IF rec.is_ref_point IS NULL THEN
|
||
|
-- Fleet moving in outer space
|
||
|
PERFORM sys.write_log( 'Fleets' , 'TRACE'::log_level , 'About to perform outer space redirect; '
|
||
|
|| 'OOFT/2 = ' || rec.flight_time || '; start(x;y)= (' || rec.os_start_x || ';' || rec.os_start_y
|
||
|
|| '); dest(x;y)= (' || rec.x || ';' || rec.y || '); time left: ' || rec.mv_state_time );
|
||
|
SELECT INTO cx , cy c_x , c_y FROM fleets.compute_current_location(
|
||
|
rec.flight_time , rec.os_start_x , rec.os_start_y , rec.x , rec.y ,
|
||
|
rec.mv_state_time );
|
||
|
PERFORM sys.write_log( 'Fleets' , 'TRACE'::log_level , 'Computed current coordinates: (' || cx
|
||
|
|| ';' || cy || ')' );
|
||
|
SELECT INTO dur , s_dur duration , s_duration
|
||
|
FROM fleets.compute_outerspace_redirect( rec.flight_time , cx , cy , dest_id );
|
||
|
PERFORM sys.write_log( 'Fleets' , 'TRACE'::log_level , 'Computed new total/state duration: '
|
||
|
|| dur || ' / ' || s_dur );
|
||
|
UPDATE fleets.ms_space SET start_x = cx , start_y = cy
|
||
|
WHERE movement_id = rec.id;
|
||
|
ELSE
|
||
|
-- Fleet moving in a system
|
||
|
cx := fleets.compute_current_orbit( rec.flight_time , rec.is_ref_point_orbit , rec.is_outwards ,
|
||
|
rec.is_past_ref_point , rec.mv_state_time );
|
||
|
SELECT INTO dur, dir , s_dur , rpid , prp duration , direction , s_duration , ref_point , past_rp
|
||
|
FROM fleets.compute_insystem_redirect( rec.flight_time , rec.is_ref_point_system , cx , dest_id );
|
||
|
UPDATE fleets.ms_system SET ref_point_id = rpid , outwards = dir , past_ref_point = prp
|
||
|
WHERE movement_id = rec.id;
|
||
|
END IF;
|
||
|
|
||
|
UPDATE fleets.movements SET time_left = dur , state_time_left = s_dur
|
||
|
WHERE fleet_id = rec.id;
|
||
|
UPDATE fleets.fleets
|
||
|
SET status = 'REDIRECTING' ,
|
||
|
penalty = rec.flight_time * 2 ,
|
||
|
location_id = dest_id
|
||
|
WHERE id = rec.id;
|
||
|
END IF;
|
||
|
END LOOP;
|
||
|
|
||
|
-- Prepare fleet departure events
|
||
|
CREATE TEMPORARY TABLE fleet_departures(
|
||
|
loc_id INT ,
|
||
|
loc_name VARCHAR(20) ,
|
||
|
own_id INT ,
|
||
|
own_name VARCHAR(20) ,
|
||
|
name VARCHAR(64) ,
|
||
|
power BIGINT ,
|
||
|
mode BOOLEAN
|
||
|
) ON COMMIT DROP;
|
||
|
INSERT INTO fleet_departures
|
||
|
SELECT fm.source_id , sn.name , f.owner_id , fon.name ,
|
||
|
f.name , fs.power , f.attacking
|
||
|
FROM fleets.fleets f
|
||
|
INNER JOIN fleets.stats_view fs ON fs.id = f.id
|
||
|
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
|
||
|
INNER JOIN naming.map_names sn ON sn.id = fm.source_id
|
||
|
INNER JOIN naming.empire_names fon ON fon.id = f.owner_id
|
||
|
WHERE f.id = ANY( fleet_ids ) AND f.owner_id = emp_id AND f.status = 'AVAILABLE';
|
||
|
PERFORM events.commit_fleet_departures( );
|
||
|
PERFORM msgs.deliver_internal( );
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Fleet movement command
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- emp_id Identifier of the empire who supposedly owns the fleets
|
||
|
-- fleet_ids List of fleets to order around
|
||
|
-- dest Name of the destination
|
||
|
--
|
||
|
-- Returns:
|
||
|
-- success Whether the destination was found or not.
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.move_fleets( emp_id INT , fleet_ids BIGINT[] , dest TEXT , OUT success BOOLEAN )
|
||
|
STRICT VOLATILE
|
||
|
SECURITY DEFINER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
dest_id INT;
|
||
|
BEGIN
|
||
|
SELECT INTO dest_id id FROM naming.map_names
|
||
|
WHERE lower( name ) = lower(dest);
|
||
|
success := FOUND;
|
||
|
|
||
|
IF success THEN
|
||
|
PERFORM fleets.set_movement_orders( emp_id , fleet_ids , dest_id );
|
||
|
END IF;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
GRANT EXECUTE ON FUNCTION fleets.move_fleets( INT , BIGINT[] , TEXT ) TO :dbuser;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Renames a set of fleets
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- emp_id Identifier of the empire who supposedly owns the fleets
|
||
|
-- fleet_ids List of fleets to rename
|
||
|
-- n_name New name
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.rename_fleets( emp_id INT , fleet_ids BIGINT[] , n_name TEXT )
|
||
|
RETURNS VOID
|
||
|
STRICT VOLATILE
|
||
|
SECURITY DEFINER
|
||
|
AS $$
|
||
|
UPDATE fleets.fleets
|
||
|
SET name = ( CASE WHEN $3 = '' THEN NULL ELSE $3 END )
|
||
|
WHERE owner_id = $1
|
||
|
AND id IN ( SELECT unnest AS id FROM unnest( $2 ) );
|
||
|
$$ LANGUAGE SQL;
|
||
|
|
||
|
GRANT EXECUTE ON FUNCTION fleets.rename_fleets( INT , BIGINT[] , TEXT ) TO :dbuser;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Prepares a fleet splitting command
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- f_id Fleet identifier
|
||
|
-- n_fleets Amount of fleets to create
|
||
|
-- nnm New name for the fleets
|
||
|
--
|
||
|
-- Returns:
|
||
|
-- success Whether the operation was successful
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.init_split( f_id BIGINT , n_fleets INT , nnm TEXT , OUT success BOOLEAN )
|
||
|
STRICT VOLATILE
|
||
|
SECURITY DEFINER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
o_name TEXT;
|
||
|
ifm BOOLEAN;
|
||
|
att BOOLEAN;
|
||
|
loc INT;
|
||
|
own INT;
|
||
|
BEGIN
|
||
|
IF n_fleets < 1 THEN
|
||
|
success := FALSE;
|
||
|
RETURN;
|
||
|
END IF;
|
||
|
|
||
|
SELECT INTO o_name , ifm , loc , att , own
|
||
|
f.name , ( m.fleet_id IS NOT NULL ) , f.location_id , f.attacking , f.owner_id
|
||
|
FROM fleets.fleets f
|
||
|
INNER JOIN emp.empires e ON e.name_id = f.owner_id
|
||
|
INNER JOIN verse.planets p ON p.name_id = f.location_id
|
||
|
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
|
||
|
WHERE f.id = f_id
|
||
|
FOR UPDATE OF f , e , p;
|
||
|
success := FOUND;
|
||
|
IF NOT success THEN
|
||
|
RETURN;
|
||
|
END IF;
|
||
|
|
||
|
CREATE TEMPORARY TABLE fleet_split_main (
|
||
|
fleet_id BIGINT ,
|
||
|
fleets INT ,
|
||
|
location INT ,
|
||
|
owner INT ,
|
||
|
attacking BOOLEAN ,
|
||
|
new_name VARCHAR(40) ,
|
||
|
moving BOOLEAN
|
||
|
) ON COMMIT DROP;
|
||
|
INSERT INTO fleet_split_main
|
||
|
VALUES ( f_id , n_fleets , loc , own , att , (CASE WHEN nnm = '' THEN o_name ELSE nnm END ) , ifm );
|
||
|
|
||
|
CREATE TEMPORARY TABLE fleet_split_ships (
|
||
|
ship_type INT ,
|
||
|
initial_amount INT ,
|
||
|
split_amount INT
|
||
|
) ON COMMIT DROP;
|
||
|
INSERT INTO fleet_split_ships
|
||
|
SELECT ship_id , amount , 0::INT
|
||
|
FROM fleets.ships
|
||
|
WHERE fleet_id = f_id;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
GRANT EXECUTE ON FUNCTION fleets.init_split( BIGINT , INT , TEXT ) TO :dbuser;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Sets the amount of ships of a given type to split off.
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- st_id Ship type identifier
|
||
|
-- n_ships Amount
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.set_split_ships( st_id INT , n_ships INT )
|
||
|
RETURNS VOID
|
||
|
STRICT VOLATILE
|
||
|
SECURITY DEFINER
|
||
|
AS $$
|
||
|
BEGIN
|
||
|
UPDATE fleet_split_ships
|
||
|
SET split_amount = n_ships
|
||
|
WHERE ship_type = st_id;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
GRANT EXECUTE ON FUNCTION fleets.set_split_ships( INT , INT ) TO :dbuser;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Verifies a fleet split command information
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.check_split()
|
||
|
RETURNS BOOLEAN
|
||
|
STRICT VOLATILE
|
||
|
SECURITY INVOKER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
n_fleets INT;
|
||
|
ssum INT;
|
||
|
nsum INT;
|
||
|
rec RECORD;
|
||
|
BEGIN
|
||
|
SELECT INTO n_fleets fleets FROM fleet_split_main;
|
||
|
ssum := 0;
|
||
|
nsum := 0;
|
||
|
FOR rec IN SELECT initial_amount , split_amount FROM fleet_split_ships
|
||
|
LOOP
|
||
|
IF rec.split_amount < 0 OR rec.split_amount * n_fleets > rec.initial_amount THEN
|
||
|
RETURN FALSE;
|
||
|
END IF;
|
||
|
ssum := ssum + rec.initial_amount - rec.split_amount * n_fleets;
|
||
|
nsum := nsum + rec.split_amount;
|
||
|
END LOOP;
|
||
|
RETURN ( ssum > 0 AND nsum > 0 );
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Executes a fleet split command information
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.split_fleet( )
|
||
|
RETURNS VOID
|
||
|
STRICT VOLATILE
|
||
|
SECURITY INVOKER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
main RECORD;
|
||
|
i INT;
|
||
|
nf_id BIGINT;
|
||
|
mv_rec fleets.movements%ROWTYPE;
|
||
|
ism_rec fleets.ms_system%ROWTYPE;
|
||
|
osm_rec fleets.ms_space%ROWTYPE;
|
||
|
old_ft INT;
|
||
|
new_ft INT;
|
||
|
sp_ft INT;
|
||
|
x REAL;
|
||
|
y REAL;
|
||
|
cx REAL;
|
||
|
cy REAL;
|
||
|
sid INT;
|
||
|
BEGIN
|
||
|
SELECT INTO main * FROM fleet_split_main;
|
||
|
|
||
|
-- Cache trajectory
|
||
|
IF main.moving THEN
|
||
|
SELECT INTO mv_rec * FROM fleets.movements WHERE fleet_id = main.fleet_id;
|
||
|
SELECT INTO ism_rec * FROM fleets.ms_system WHERE movement_id = main.fleet_id;
|
||
|
SELECT INTO osm_rec * FROM fleets.ms_space WHERE movement_id = main.fleet_id;
|
||
|
SELECT INTO old_ft flight_time FROM fleets.stats_view WHERE id = main.fleet_id;
|
||
|
END IF;
|
||
|
|
||
|
-- Update existing fleet
|
||
|
UPDATE fleets.ships s
|
||
|
SET amount = amount - fss.split_amount * main.fleets
|
||
|
FROM fleet_split_ships fss
|
||
|
WHERE fleet_id = main.fleet_id AND s.ship_id = fss.ship_type;
|
||
|
DELETE FROM fleets.ships WHERE fleet_id = main.fleet_id AND amount = 0;
|
||
|
|
||
|
-- Did the speed change?
|
||
|
IF main.moving THEN
|
||
|
SELECT INTO new_ft flight_time FROM fleets.stats_view WHERE id = main.fleet_id;
|
||
|
IF new_ft <> old_ft THEN
|
||
|
IF ism_rec IS NULL THEN
|
||
|
-- Outer space movement
|
||
|
SELECT INTO x , y s.x::REAL , s.y::REAL
|
||
|
FROM verse.planets p
|
||
|
INNER JOIN verse.systems s ON s.id = p.system_id
|
||
|
WHERE p.name_id = main.location;
|
||
|
SELECT INTO cx , cy c_x , c_y FROM fleets.compute_current_location(
|
||
|
old_ft , osm_rec.start_x , osm_rec.start_y , x , y ,
|
||
|
mv_rec.state_time_left );
|
||
|
UPDATE fleets.ms_space
|
||
|
SET start_x = cx , start_y = cy
|
||
|
WHERE movement_id = main.fleet_id;
|
||
|
UPDATE fleets.movements m
|
||
|
SET time_left = r.duration , state_time_left = r.s_duration
|
||
|
FROM fleets.compute_outerspace_redirect( new_ft , cx , cy , main.location ) r
|
||
|
WHERE m.fleet_id = main.fleet_id;
|
||
|
ELSE
|
||
|
-- System movement
|
||
|
SELECT INTO y , sid orbit , system_id
|
||
|
FROM verse.planets
|
||
|
WHERE name_id = ism_rec.ref_point_id;
|
||
|
x := fleets.compute_current_orbit( old_ft , y::INT , ism_rec.outwards ,
|
||
|
ism_rec.past_ref_point , mv_rec.state_time_left );
|
||
|
UPDATE fleets.movements m
|
||
|
SET time_left = r.duration , state_time_left = r.s_duration
|
||
|
FROM fleets.compute_insystem_redirect( new_ft , sid , x , main.location ) r
|
||
|
WHERE m.fleet_id = main.fleet_id;
|
||
|
END IF;
|
||
|
END IF;
|
||
|
END IF;
|
||
|
|
||
|
sp_ft := NULL;
|
||
|
FOR i IN 1 .. main.fleets
|
||
|
LOOP
|
||
|
-- Main fleet record
|
||
|
INSERT INTO fleets.fleets ( owner_id , location_id , name , attacking , status , penalty )
|
||
|
VALUES ( main.owner , main.location , main.new_name , main.attacking , 'AVAILABLE' , 0 )
|
||
|
RETURNING id INTO nf_id;
|
||
|
|
||
|
-- Fleet ships
|
||
|
INSERT INTO fleets.ships ( fleet_id , ship_id , amount , damage )
|
||
|
SELECT nf_id , s.ship_type , s.split_amount , 0
|
||
|
FROM fleet_split_ships s
|
||
|
WHERE s.split_amount > 0;
|
||
|
|
||
|
IF main.moving THEN
|
||
|
IF sp_ft IS NULL THEN
|
||
|
SELECT INTO sp_ft flight_time FROM fleets.stats_view WHERE id = nf_id;
|
||
|
IF sp_ft <> old_ft THEN
|
||
|
IF ism_rec IS NULL THEN
|
||
|
-- Outer space movement
|
||
|
SELECT INTO x , y s.x::REAL , s.y::REAL
|
||
|
FROM verse.planets p
|
||
|
INNER JOIN verse.systems s ON s.id = p.system_id
|
||
|
WHERE p.name_id = main.location;
|
||
|
SELECT INTO cx , cy c_x , c_y FROM fleets.compute_current_location(
|
||
|
old_ft , osm_rec.start_x , osm_rec.start_y , x , y ,
|
||
|
mv_rec.state_time_left );
|
||
|
osm_rec.start_x := cx;
|
||
|
osm_rec.start_y := cy;
|
||
|
SELECT INTO mv_rec.time_left , mv_rec.state_time_left
|
||
|
duration , s_duration
|
||
|
FROM fleets.compute_outerspace_redirect( sp_ft , cx , cy , main.location );
|
||
|
ELSE
|
||
|
-- System movement
|
||
|
SELECT INTO y , sid orbit , system_id
|
||
|
FROM verse.planets
|
||
|
WHERE name_id = ism_rec.ref_point_id;
|
||
|
x := fleets.compute_current_orbit( old_ft , y::INT , ism_rec.outwards ,
|
||
|
ism_rec.past_ref_point , mv_rec.state_time_left );
|
||
|
SELECT INTO mv_rec.time_left , mv_rec.state_time_left
|
||
|
duration , s_duration
|
||
|
FROM fleets.compute_insystem_redirect( sp_ft , sid , x , main.location );
|
||
|
END IF;
|
||
|
END IF;
|
||
|
END IF;
|
||
|
|
||
|
-- Insert fleet movement records
|
||
|
INSERT INTO fleets.movements ( fleet_id , source_id , time_left , state_time_left )
|
||
|
VALUES ( nf_id , mv_rec.source_id , mv_rec.time_left , mv_rec.state_time_left );
|
||
|
IF ism_rec IS NULL THEN
|
||
|
INSERT INTO fleets.ms_space ( movement_id , start_x , start_y )
|
||
|
VALUES ( nf_id , osm_rec.start_x , osm_rec.start_y );
|
||
|
ELSE
|
||
|
INSERT INTO fleets.ms_system ( movement_id , ref_point_id , outwards , past_ref_point )
|
||
|
VALUES ( nf_id , ism_rec.ref_point_id , ism_rec.outwards , ism_rec.past_ref_point );
|
||
|
END IF;
|
||
|
END IF;
|
||
|
END LOOP;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Finalises a fleet split command
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- simulate Whether the split command was only being simulated
|
||
|
--
|
||
|
-- Returns:
|
||
|
-- success Whether the operation was / would have been successful
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.execute_split( simulate BOOLEAN , OUT success BOOLEAN )
|
||
|
STRICT VOLATILE
|
||
|
SECURITY DEFINER
|
||
|
AS $$
|
||
|
BEGIN
|
||
|
success := fleets.check_split();
|
||
|
IF success AND NOT simulate THEN
|
||
|
PERFORM fleets.split_fleet();
|
||
|
END IF;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
GRANT EXECUTE ON FUNCTION fleets.execute_split( BOOLEAN ) TO :dbuser;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Set fleet mode
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- e_id Empire who supposedly owns the fleets
|
||
|
-- f_ids Fleet identifiers
|
||
|
-- att Whether the fleets are to be set to attack
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.set_mode( e_id INT , f_ids BIGINT[] , att BOOLEAN )
|
||
|
RETURNS VOID
|
||
|
STRICT VOLATILE
|
||
|
SECURITY DEFINER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
rec RECORD;
|
||
|
BEGIN
|
||
|
-- Prepare events table
|
||
|
CREATE TEMPORARY TABLE fleet_switches(
|
||
|
loc_id INT ,
|
||
|
loc_name VARCHAR(20) ,
|
||
|
own_id INT ,
|
||
|
own_name VARCHAR(20) ,
|
||
|
name VARCHAR(64) ,
|
||
|
power BIGINT ,
|
||
|
mode BOOLEAN
|
||
|
) ON COMMIT DROP;
|
||
|
|
||
|
-- Lock records
|
||
|
PERFORM f.id FROM fleets.fleets f
|
||
|
INNER JOIN verse.planets p ON p.name_id = f.location_id
|
||
|
INNER JOIN unnest( f_ids ) fid ON f.id = fid
|
||
|
WHERE f.owner_id = e_id AND f.attacking <> att
|
||
|
FOR UPDATE OF f , p;
|
||
|
|
||
|
-- Handle moving fleets
|
||
|
UPDATE fleets.fleets f SET attacking = att
|
||
|
FROM fleets.movements m
|
||
|
WHERE f.owner_id = e_id AND f.id IN ( SELECT * FROM unnest( f_ids ) )
|
||
|
AND m.fleet_id = f.id AND f.attacking <> att;
|
||
|
|
||
|
-- Handle fleets on planets
|
||
|
FOR rec IN SELECT DISTINCT f.location_id AS location , ep.empire_id AS planet_owner ,
|
||
|
b.id AS battle , ( el.enemy IS NOT NULL ) AS enemy ,
|
||
|
( v.status = 'PROCESSED' AND b.id IS NULL ) AS on_vacation
|
||
|
FROM fleets.fleets f
|
||
|
INNER JOIN unnest( f_ids ) fid ON f.id = fid
|
||
|
LEFT OUTER JOIN battles.battles b
|
||
|
ON b.location_id = f.location_id AND b.last_tick IS NULL
|
||
|
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
|
||
|
LEFT OUTER JOIN emp.planets ep ON ep.planet_id = f.location_id
|
||
|
LEFT OUTER JOIN emp.enemies el
|
||
|
ON el.empire = ep.empire_id AND el.enemy = e_id
|
||
|
LEFT OUTER JOIN naming.empire_names en ON en.id = ep.empire_id
|
||
|
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id
|
||
|
WHERE f.owner_id = e_id AND m.fleet_id IS NULL AND f.attacking <> att
|
||
|
LOOP
|
||
|
-- Can't switch on own planets, on planets whose owner have the fleets' owner in their EL
|
||
|
-- or on planets which have entered vacation mode
|
||
|
CONTINUE WHEN e_id = rec.planet_owner OR rec.enemy OR rec.on_vacation;
|
||
|
|
||
|
-- Prepare events
|
||
|
INSERT INTO fleet_switches
|
||
|
SELECT f.location_id , ln.name , f.owner_id , fon.name ,
|
||
|
f.name , fs.power , att
|
||
|
FROM fleets.fleets f
|
||
|
INNER JOIN emp.planets ep ON f.location_id = ep.planet_id
|
||
|
INNER JOIN fleets.stats_view fs ON fs.id = f.id
|
||
|
INNER JOIN naming.map_names ln ON ln.id = f.location_id
|
||
|
INNER JOIN naming.empire_names fon ON fon.id = f.owner_id
|
||
|
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
|
||
|
WHERE f.owner_id = e_id AND f.location_id = rec.location
|
||
|
AND m.fleet_id IS NULL;
|
||
|
|
||
|
-- Set fleets mode
|
||
|
UPDATE fleets.fleets f
|
||
|
SET attacking = att ,
|
||
|
status = 'REDEPLOYING' ,
|
||
|
penalty = ( CASE
|
||
|
WHEN f2.penalty > ( 1 + fs.flight_time * ( CASE WHEN att THEN 40 ELSE 10 END ) )
|
||
|
THEN f2.penalty
|
||
|
ELSE ( 1 + fs.flight_time * ( CASE WHEN att THEN 40 ELSE 10 END ) )
|
||
|
END )
|
||
|
FROM fleets.fleets f2
|
||
|
INNER JOIN fleets.stats_view fs ON fs.id = f2.id
|
||
|
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f2.id
|
||
|
WHERE f2.owner_id = e_id AND f2.location_id = rec.location
|
||
|
AND m.fleet_id IS NULL AND f2.id = f.id;
|
||
|
|
||
|
-- Update battle
|
||
|
PERFORM battles.set_mode( rec.battle , e_id , att );
|
||
|
END LOOP;
|
||
|
|
||
|
PERFORM events.commit_fleet_switches( FALSE );
|
||
|
PERFORM msgs.deliver_internal( );
|
||
|
|
||
|
DROP TABLE fleet_switches;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
GRANT EXECUTE ON FUNCTION fleets.set_mode( INT , BIGINT[] , BOOLEAN ) TO :dbuser;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Disband fleets
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- e_id Empire who supposedly owns the fleets
|
||
|
-- f_ids Fleet identifiers
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.disband( e_id INT , f_ids BIGINT[] )
|
||
|
RETURNS VOID
|
||
|
STRICT VOLATILE
|
||
|
SECURITY DEFINER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
rec RECORD;
|
||
|
BEGIN
|
||
|
-- Lock all fleets and, if necessary, remove them from battles
|
||
|
FOR rec IN SELECT f.id AS fleet ,
|
||
|
( CASE
|
||
|
WHEN m.fleet_id IS NULL AND f.status <> 'DEPLOYING' THEN
|
||
|
b.id
|
||
|
ELSE
|
||
|
NULL
|
||
|
END ) AS battle
|
||
|
FROM fleets.fleets f
|
||
|
INNER JOIN unnest( f_ids ) fid ON f.id = fid
|
||
|
INNER JOIN verse.planets p ON p.name_id = f.location_id
|
||
|
LEFT OUTER JOIN battles.battles b
|
||
|
ON b.location_id = f.location_id AND b.last_tick IS NULL
|
||
|
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
|
||
|
WHERE f.owner_id = e_id
|
||
|
FOR UPDATE OF p , f
|
||
|
LOOP
|
||
|
PERFORM battles.remove_fleet( rec.battle , rec.fleet , 'DISBAND'::battle_fleet_change , sys.get_tick( ) );
|
||
|
END LOOP;
|
||
|
|
||
|
-- Delete fleets
|
||
|
DELETE FROM fleets.fleets
|
||
|
WHERE id IN ( SELECT * FROM unnest( f_ids ) ) AND owner_id = e_id;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
GRANT EXECUTE ON FUNCTION fleets.disband( INT , BIGINT[] ) TO :dbuser;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Inflicts battle damage to a fleet
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- f_id Fleet identifier
|
||
|
-- dmg Damage to inflict
|
||
|
-- b_id Battle identifier
|
||
|
-- tick Current tick
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.inflict_battle_damage( f_id BIGINT , dmg REAL , b_id BIGINT , tick BIGINT )
|
||
|
RETURNS VOID
|
||
|
STRICT VOLATILE
|
||
|
SECURITY INVOKER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
f_power BIGINT;
|
||
|
f_att BOOLEAN;
|
||
|
e_id INT;
|
||
|
bp_id BIGINT;
|
||
|
bf_id BIGINT;
|
||
|
rec RECORD;
|
||
|
st_dmg REAL;
|
||
|
n_dest INT;
|
||
|
found INT;
|
||
|
deleted INT;
|
||
|
BEGIN
|
||
|
PERFORM sys.write_log( 'BattleUpdate' , 'TRACE'::log_level , 'Inflicting '
|
||
|
|| dmg || ' damage to fleet #' || f_id );
|
||
|
|
||
|
-- Get total fleet power and battle protagonist
|
||
|
SELECT INTO f_power , e_id , f_att fs.power , f.owner_id , f.attacking
|
||
|
FROM fleets.fleets f
|
||
|
INNER JOIN fleets.stats_view fs USING( id )
|
||
|
WHERE id = f_id;
|
||
|
bp_id := battles.goc_protagonist( b_id , e_id , f_att , tick );
|
||
|
bf_id := NULL;
|
||
|
|
||
|
found := 0;
|
||
|
deleted := 0;
|
||
|
FOR rec IN SELECT s.ship_id , ( s.amount * sd.power ) AS t_power ,
|
||
|
sd.power AS s_power , s.damage AS damage ,
|
||
|
s.amount AS amount
|
||
|
FROM fleets.ships s
|
||
|
INNER JOIN tech.ships sd ON sd.buildable_id = s.ship_id
|
||
|
WHERE s.fleet_id = f_id
|
||
|
LOOP
|
||
|
-- Compute ships to destroy
|
||
|
found := found + 1;
|
||
|
st_dmg := rec.damage + ( dmg * rec.t_power / f_power ) / rec.s_power;
|
||
|
n_dest := floor( st_dmg );
|
||
|
|
||
|
IF n_dest >= rec.amount THEN
|
||
|
-- All ships destroyed
|
||
|
deleted := deleted + 1;
|
||
|
DELETE FROM fleets.ships WHERE fleet_id = f_id AND ship_id = rec.ship_id;
|
||
|
n_dest := rec.amount;
|
||
|
ELSE
|
||
|
-- Inflict damage
|
||
|
UPDATE fleets.ships
|
||
|
SET amount = amount - n_dest ,
|
||
|
damage = st_dmg - n_dest
|
||
|
WHERE fleet_id = f_id AND ship_id = rec.ship_id;
|
||
|
END IF;
|
||
|
|
||
|
IF n_dest > 0 THEN
|
||
|
-- Update fleet change record
|
||
|
IF bf_id IS NULL THEN
|
||
|
bf_id := battles.goc_fleet_change( bp_id , tick , 'BATTLE'::battle_fleet_change );
|
||
|
END IF;
|
||
|
PERFORM battles.add_fleet_change( bf_id , rec.ship_id , - n_dest );
|
||
|
END IF;
|
||
|
END LOOP;
|
||
|
|
||
|
-- If all ships were destroyed, delete the fleet
|
||
|
IF found = deleted THEN
|
||
|
DELETE FROM fleets.fleets WHERE id = f_id;
|
||
|
END IF;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Inflicts debt-related damage to all fleets of an empire
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- e_id Empire identifer
|
||
|
-- t_upkeep Total fleet upkeep
|
||
|
-- debt Daily debt
|
||
|
-- d_ratio Debt damage ratio
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.handle_debt( e_id INT , t_upkeep REAL , debt REAL , d_ratio REAL )
|
||
|
RETURNS VOID
|
||
|
STRICT VOLATILE
|
||
|
SECURITY INVOKER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
tot_damage REAL;
|
||
|
f_rec RECORD;
|
||
|
s_rec RECORD;
|
||
|
n_found INT;
|
||
|
n_killed INT;
|
||
|
s_killed INT;
|
||
|
s_damage REAL;
|
||
|
n_ships INT;
|
||
|
tick BIGINT;
|
||
|
bp_id BIGINT;
|
||
|
bf_id BIGINT;
|
||
|
mv_rec fleets.movements%ROWTYPE;
|
||
|
ism_rec fleets.ms_system%ROWTYPE;
|
||
|
osm_rec fleets.ms_space%ROWTYPE;
|
||
|
x REAL;
|
||
|
y REAL;
|
||
|
cx REAL;
|
||
|
cy REAL;
|
||
|
sid INT;
|
||
|
BEGIN
|
||
|
tick := sys.get_tick( ) - 1;
|
||
|
tot_damage := t_upkeep * d_ratio / debt;
|
||
|
PERFORM sys.write_log( 'EmpireDebt' , 'DEBUG'::log_level , 'Inflicting debt damage to fleets; total upkeep: '
|
||
|
|| t_upkeep || ', damage ratio: ' || d_ratio || ', total damage: ' || tot_damage );
|
||
|
|
||
|
FOR f_rec IN SELECT f.id AS fleet , f.status , f.location_id AS location ,
|
||
|
( m.fleet_id IS NOT NULL ) AS moving , b.id AS battle ,
|
||
|
fs.flight_time , f.attacking
|
||
|
FROM fleets.fleets f
|
||
|
INNER JOIN fleets.stats_view fs ON fs.id = f.id
|
||
|
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
|
||
|
LEFT OUTER JOIN battles.battles b
|
||
|
ON b.location_id = f.location_id AND b.last_tick IS NULL
|
||
|
WHERE f.owner_id = e_id
|
||
|
FOR UPDATE OF f
|
||
|
LOOP
|
||
|
-- Get battle information
|
||
|
IF f_rec.battle IS NOT NULL AND NOT f_rec.moving AND f_rec.status <> 'DEPLOYING'
|
||
|
THEN
|
||
|
bp_id := battles.goc_protagonist( f_rec.battle , e_id , f_rec.attacking , tick );
|
||
|
bf_id := NULL;
|
||
|
END IF;
|
||
|
|
||
|
-- Damage ships
|
||
|
n_found := 0;
|
||
|
n_killed := 0;
|
||
|
s_killed := 0;
|
||
|
FOR s_rec IN SELECT s.ship_id AS ship , s.amount AS amount , s.damage AS damage ,
|
||
|
( d.upkeep * s.amount )::REAL AS upkeep
|
||
|
FROM fleets.ships s
|
||
|
INNER JOIN tech.buildables d ON d.name_id = s.ship_id
|
||
|
WHERE s.fleet_id = f_rec.fleet
|
||
|
LOOP
|
||
|
n_found := n_found + 1;
|
||
|
s_damage := s_rec.damage + tot_damage * s_rec.upkeep / t_upkeep;
|
||
|
n_ships := floor( s_damage );
|
||
|
IF n_ships >= s_rec.amount
|
||
|
THEN
|
||
|
-- All ships destroyed
|
||
|
DELETE FROM fleets.ships WHERE fleet_id = f_rec.fleet AND ship_id = s_rec.ship;
|
||
|
n_killed := n_killed + 1;
|
||
|
s_killed := s_killed + s_rec.amount;
|
||
|
n_ships := s_rec.amount;
|
||
|
ELSE
|
||
|
-- Simple damage
|
||
|
UPDATE fleets.ships
|
||
|
SET amount = s_rec.amount - n_ships ,
|
||
|
damage = s_damage - n_ships
|
||
|
WHERE fleet_id = f_rec.fleet AND ship_id = s_rec.ship;
|
||
|
s_killed := s_killed + n_ships;
|
||
|
END IF;
|
||
|
|
||
|
IF n_ships > 0 AND f_rec.battle IS NOT NULL AND NOT f_rec.moving AND f_rec.status <> 'DEPLOYING'
|
||
|
THEN
|
||
|
-- Update battle
|
||
|
IF bf_id IS NULL THEN
|
||
|
bf_id := battles.goc_fleet_change( bp_id , tick , 'DISBAND'::battle_fleet_change );
|
||
|
END IF;
|
||
|
PERFORM battles.add_fleet_change( bf_id , s_rec.ship , - n_ships );
|
||
|
END IF;
|
||
|
END LOOP;
|
||
|
|
||
|
-- No ships destroyed
|
||
|
CONTINUE WHEN s_killed = 0;
|
||
|
|
||
|
IF n_killed = n_found
|
||
|
THEN
|
||
|
-- Destroy fleet
|
||
|
DELETE FROM fleets.fleets WHERE id = f_rec.fleet;
|
||
|
ELSEIF f_rec.moving AND n_killed > 0
|
||
|
THEN
|
||
|
-- Flight time may have changed, update fleet accordingly
|
||
|
SELECT INTO n_found flight_time FROM fleets.stats_view WHERE id = f_rec.fleet;
|
||
|
CONTINUE WHEN n_found = f_rec.flight_time;
|
||
|
|
||
|
-- Get movement records
|
||
|
SELECT INTO mv_rec * FROM fleets.movements WHERE fleet_id = f_rec.fleet;
|
||
|
SELECT INTO ism_rec * FROM fleets.ms_system WHERE movement_id = f_rec.fleet;
|
||
|
SELECT INTO osm_rec * FROM fleets.ms_space WHERE movement_id = f_rec.fleet;
|
||
|
|
||
|
IF ism_rec IS NULL THEN
|
||
|
-- Outer space movement
|
||
|
SELECT INTO x , y s.x::REAL , s.y::REAL
|
||
|
FROM verse.planets p
|
||
|
INNER JOIN verse.systems s ON s.id = p.system_id
|
||
|
WHERE p.name_id = f_rec.location;
|
||
|
SELECT INTO cx , cy c_x , c_y FROM fleets.compute_current_location(
|
||
|
f_rec.flight_time , osm_rec.start_x , osm_rec.start_y , x , y ,
|
||
|
mv_rec.state_time_left );
|
||
|
UPDATE fleets.ms_space
|
||
|
SET start_x = cx , start_y = cy
|
||
|
WHERE movement_id = f_rec.fleet;
|
||
|
UPDATE fleets.movements m
|
||
|
SET time_left = r.duration , state_time_left = r.s_duration
|
||
|
FROM fleets.compute_outerspace_redirect( n_found , cx , cy , f_rec.location ) r
|
||
|
WHERE m.fleet_id = f_rec.fleet;
|
||
|
ELSE
|
||
|
-- System movement
|
||
|
SELECT INTO y , sid orbit , system_id
|
||
|
FROM verse.planets
|
||
|
WHERE name_id = ism_rec.ref_point_id;
|
||
|
x := fleets.compute_current_orbit( f_rec.flight_time , y::INT , ism_rec.outwards ,
|
||
|
ism_rec.past_ref_point , mv_rec.state_time_left );
|
||
|
UPDATE fleets.movements m
|
||
|
SET time_left = r.duration , state_time_left = r.s_duration
|
||
|
FROM fleets.compute_insystem_redirect( n_found , sid , x , f_rec.location ) r
|
||
|
WHERE m.fleet_id = f_rec.fleet;
|
||
|
END IF;
|
||
|
END IF;
|
||
|
END LOOP;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Merge fleets
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- e_id Empire who supposedly owns the fleets
|
||
|
-- f_ids Fleet identifiers
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION fleets.merge( e_id INT , f_ids BIGINT[] )
|
||
|
RETURNS VOID
|
||
|
STRICT VOLATILE
|
||
|
SECURITY DEFINER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
rec RECORD;
|
||
|
BEGIN
|
||
|
-- Create temporary tables
|
||
|
CREATE TEMPORARY TABLE merged_fleets(
|
||
|
location INT ,
|
||
|
fleet BIGINT ,
|
||
|
n_merged INT DEFAULT 1
|
||
|
) ON COMMIT DROP;
|
||
|
CREATE TEMPORARY TABLE merged_ships( LIKE fleets.ships ) ON COMMIT DROP;
|
||
|
|
||
|
-- Find all fleets
|
||
|
FOR rec IN SELECT f.id AS fleet , f.location_id AS location
|
||
|
FROM fleets.fleets f
|
||
|
INNER JOIN unnest( f_ids ) fid ON f.id = fid
|
||
|
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
|
||
|
WHERE f.status = 'AVAILABLE' AND f.owner_id = e_id AND m.fleet_id IS NULL
|
||
|
FOR UPDATE OF f
|
||
|
LOOP
|
||
|
UPDATE merged_fleets SET n_merged = n_merged + 1 WHERE location = rec.location;
|
||
|
|
||
|
IF FOUND THEN
|
||
|
-- Update existing record
|
||
|
UPDATE merged_ships ms
|
||
|
SET amount = ms.amount + s.amount ,
|
||
|
damage = ms.damage + s.damage
|
||
|
FROM merged_fleets f , fleets.ships s
|
||
|
WHERE f.location = rec.location AND ms.fleet_id = f.fleet
|
||
|
AND s.fleet_id = rec.fleet AND ms.ship_id = s.ship_id;
|
||
|
DELETE FROM fleets.fleets WHERE id = rec.fleet;
|
||
|
ELSE
|
||
|
-- Create new record
|
||
|
INSERT INTO merged_fleets ( location , fleet )
|
||
|
VALUES ( rec.location , rec.fleet );
|
||
|
INSERT INTO merged_ships (fleet_id , ship_id , amount , damage )
|
||
|
SELECT rec.fleet , s.buildable_id , 0 , 0
|
||
|
FROM tech.ships s;
|
||
|
UPDATE merged_ships ms
|
||
|
SET amount = ms.amount + s.amount ,
|
||
|
damage = ms.damage + s.damage
|
||
|
FROM merged_fleets f , fleets.ships s
|
||
|
WHERE f.location = rec.location AND ms.fleet_id = f.fleet
|
||
|
AND s.fleet_id = rec.fleet AND ms.ship_id = s.ship_id;
|
||
|
DELETE FROM fleets.ships WHERE fleet_id = rec.fleet;
|
||
|
END IF;
|
||
|
END LOOP;
|
||
|
|
||
|
INSERT INTO fleets.ships
|
||
|
SELECT * FROM merged_ships WHERE amount > 0;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
GRANT EXECUTE ON FUNCTION fleets.merge( INT , BIGINT[] ) TO :dbuser;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Fleet locations list
|
||
|
--
|
||
|
|
||
|
CREATE VIEW fleets.locations_list_view
|
||
|
AS SELECT ep.empire_id AS empire , ep.planet_id AS location , FALSE AS attacking
|
||
|
FROM emp.planets ep
|
||
|
UNION SELECT f.owner_id AS empire , f.location_id AS location , f.attacking AS attacking
|
||
|
FROM fleets.fleets f
|
||
|
LEFT OUTER JOIN fleets.movements m
|
||
|
ON m.fleet_id = f.id
|
||
|
WHERE m.fleet_id IS NULL;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Fleet stats
|
||
|
--
|
||
|
|
||
|
CREATE VIEW fleets.stats_view
|
||
|
AS SELECT f.id ,
|
||
|
sum( fs.amount * fsd.power ) AS power ,
|
||
|
max( fsd.flight_time ) AS flight_time
|
||
|
FROM fleets.fleets f
|
||
|
INNER JOIN fleets.ships fs
|
||
|
ON fs.fleet_id = f.id
|
||
|
INNER JOIN tech.ships fsd
|
||
|
ON fsd.buildable_id = fs.ship_id
|
||
|
GROUP BY f.id;
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Fleet locations view
|
||
|
--
|
||
|
|
||
|
CREATE VIEW fleets.locations_view
|
||
|
AS SELECT llv.* , mv.name , mv.x , mv.y , mv.orbit , mv.picture , mv.tag ,
|
||
|
floor( p.population )::BIGINT AS population ,
|
||
|
floor( verse.adjust_production( verse.get_raw_production( p.name_id , 'DEF' ) , ph.current / p.population ) )::BIGINT AS defence ,
|
||
|
bcs.id AS battle ,
|
||
|
( CASE WHEN llv.attacking THEN bcs.attack ELSE bcs.defence END ) AS friendly_power ,
|
||
|
( CASE WHEN llv.attacking THEN bcs.defence ELSE bcs.attack END ) AS hostile_power ,
|
||
|
( ep.empire_id = llv.empire ) AS is_own ,
|
||
|
( v.account_id IS NOT NULL AND bcs.id IS NULL ) AS on_vacation
|
||
|
FROM fleets.locations_list_view llv
|
||
|
INNER JOIN verse.planets p ON p.name_id = llv.location
|
||
|
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
|
||
|
INNER JOIN verse.map_view mv ON mv.id = p.name_id
|
||
|
LEFT OUTER JOIN battles.current_status bcs ON bcs.location = llv.location
|
||
|
LEFT OUTER JOIN emp.planets ep ON ep.planet_id = p.name_id
|
||
|
LEFT OUTER JOIN naming.empire_names en ON en.id = ep.empire_id
|
||
|
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id AND v.status = 'PROCESSED'
|
||
|
ORDER BY mv.x , mv.y , mv.orbit;
|
||
|
|
||
|
GRANT SELECT ON fleets.locations_view TO :dbuser;
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Fleet owners view
|
||
|
--
|
||
|
|
||
|
|
||
|
CREATE VIEW fleets.owners_view
|
||
|
AS SELECT DISTINCT llv.empire , llv.location , f.owner_id AS id , n.name AS name ,
|
||
|
( CASE
|
||
|
WHEN f.owner_id = llv.empire THEN 'OWN'
|
||
|
WHEN f.attacking = llv.attacking THEN 'ALLIED'
|
||
|
ELSE 'ENEMY'
|
||
|
END )::empire_relation_type AS relation
|
||
|
FROM fleets.locations_list_view llv
|
||
|
INNER JOIN fleets.fleets f
|
||
|
ON f.location_id = llv.location
|
||
|
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 m.fleet_id IS NULL;
|
||
|
|
||
|
GRANT SELECT ON fleets.owners_view TO :dbuser;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Static fleets view
|
||
|
--
|
||
|
|
||
|
CREATE VIEW fleets.static_fleets
|
||
|
AS SELECT ov.empire , ov.location , ov.id AS owner ,
|
||
|
f.id , f.name , f.status , f.penalty ,
|
||
|
fs.power , fs.flight_time * 2 AS flight_time
|
||
|
FROM fleets.owners_view ov
|
||
|
INNER JOIN fleets.fleets f
|
||
|
ON f.location_id = ov.location AND f.owner_id = ov.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 m.fleet_id IS NULL;
|
||
|
|
||
|
GRANT SELECT ON fleets.static_fleets TO :dbuser;
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Location of fleets moving in outer space
|
||
|
--
|
||
|
|
||
|
CREATE VIEW fleets.outer_space_fleets
|
||
|
AS SELECT s.movement_id AS id , m.state_time_left AS time_left ,
|
||
|
s.start_x AS x0 , s.start_y AS y0 ,
|
||
|
ts.x::REAL AS x1 , ts.y::REAL AS y1
|
||
|
FROM fleets.ms_space s
|
||
|
INNER JOIN fleets.movements m ON m.fleet_id = s.movement_id
|
||
|
INNER JOIN fleets.fleets f ON m.fleet_id = f.id
|
||
|
INNER JOIN verse.planets p ON p.name_id = f.location_id
|
||
|
INNER JOIN verse.systems ts ON ts.id = p.system_id;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Location of fleets moving inside systems
|
||
|
--
|
||
|
|
||
|
CREATE VIEW fleets.system_fleets
|
||
|
AS SELECT s.movement_id AS id , iss.x AS x , iss.y AS y ,
|
||
|
n.id AS planet , n.name AS name
|
||
|
FROM fleets.ms_system s
|
||
|
INNER JOIN verse.planets isp ON isp.name_id = s.ref_point_id
|
||
|
INNER JOIN verse.systems iss ON iss.id = isp.system_id
|
||
|
INNER JOIN naming.map_names n ON n.id = isp.name_id;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Moving fleets view
|
||
|
--
|
||
|
|
||
|
CREATE VIEW fleets.moving_fleets
|
||
|
AS SELECT f.owner_id AS empire , f.id , f.name ,
|
||
|
f.status , f.penalty , f.attacking ,
|
||
|
fs.power , fs.flight_time * 2 AS flight_time ,
|
||
|
m.time_left ,
|
||
|
m.source_id AS from_id , sn.name AS from_name ,
|
||
|
f.location_id AS to_id , dn.name AS to_name ,
|
||
|
( CASE
|
||
|
WHEN osf.id IS NULL THEN isf.x
|
||
|
ELSE ( osf.x1 - osf.time_left::REAL * ( osf.x1 - osf.x0 )
|
||
|
/ fleets.compute_outerspace_duration( fs.flight_time , osf.x0 , osf.y0 , osf.x1 , osf.y1 ) )
|
||
|
END )::REAL AS cx ,
|
||
|
( CASE
|
||
|
WHEN osf.id IS NULL THEN isf.y
|
||
|
ELSE ( osf.y1 - osf.time_left::REAL * ( osf.y1 - osf.y0 )
|
||
|
/ fleets.compute_outerspace_duration( fs.flight_time , osf.x0 , osf.y0 , osf.x1 , osf.y1 ) )
|
||
|
END )::REAL AS cy ,
|
||
|
( CASE
|
||
|
WHEN osf.id IS NULL THEN isf.planet
|
||
|
ELSE NULL
|
||
|
END )::INT AS nearest_id ,
|
||
|
( CASE
|
||
|
WHEN osf.id IS NULL THEN isf.name
|
||
|
ELSE NULL
|
||
|
END )::TEXT AS nearest_name
|
||
|
FROM fleets.fleets f
|
||
|
INNER JOIN fleets.movements m ON m.fleet_id = f.id
|
||
|
INNER JOIN fleets.stats_view fs ON fs.id = f.id
|
||
|
INNER JOIN naming.map_names sn ON sn.id = m.source_id
|
||
|
INNER JOIN naming.map_names dn ON dn.id = f.location_id
|
||
|
LEFT OUTER JOIN fleets.system_fleets isf ON isf.id = m.fleet_id
|
||
|
LEFT OUTER JOIN fleets.outer_space_fleets osf ON osf.id = f.id;
|
||
|
|
||
|
GRANT SELECT ON fleets.moving_fleets TO :dbuser;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- List of fleets visible to an empire
|
||
|
--
|
||
|
|
||
|
CREATE VIEW fleets.visible_fleets_list
|
||
|
AS SELECT empire , id FROM fleets.static_fleets
|
||
|
UNION SELECT empire , id FROM fleets.moving_fleets;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- List of fleets ships
|
||
|
--
|
||
|
|
||
|
CREATE VIEW fleets.ships_view
|
||
|
AS SELECT vfl.empire , vfl.id , fs.ship_id , fs.amount ,
|
||
|
( fs.amount * fsd.power ) AS power ,
|
||
|
t.translated_string AS name
|
||
|
FROM fleets.visible_fleets_list vfl
|
||
|
INNER JOIN naming.empire_names en ON vfl.empire = en.id
|
||
|
INNER JOIN users.credentials c ON c.address_id = en.owner_id
|
||
|
INNER JOIN fleets.ships fs ON fs.fleet_id = vfl.id
|
||
|
INNER JOIN tech.ships fsd ON fsd.buildable_id = fs.ship_id
|
||
|
INNER JOIN defs.translations t ON t.lang_id = c.language_id AND t.string_id = fsd.buildable_id
|
||
|
ORDER BY fsd.power;
|
||
|
|
||
|
GRANT SELECT ON fleets.ships_view TO :dbuser;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Short view for static fleets
|
||
|
--
|
||
|
|
||
|
CREATE VIEW fleets.short_static_fleets
|
||
|
AS SELECT sf.empire , sf.location AS location_id ,
|
||
|
fl.name AS location_name ,
|
||
|
fl.x::REAL AS x , fl.y::REAL AS y ,
|
||
|
sf.id , sf.name , sf.status , sf.penalty ,
|
||
|
fl.attacking , sf.power , sf.flight_time
|
||
|
FROM fleets.static_fleets sf
|
||
|
INNER JOIN fleets.locations_view fl USING( location , empire )
|
||
|
WHERE sf.empire = sf.owner;
|
||
|
|
||
|
GRANT SELECT ON fleets.short_static_fleets TO :dbuser;
|