This repository has been archived on 2024-07-18. You can view files and clone it, but cannot push or open issues or pull requests.
lwb6/legacyworlds-server/legacyworlds-server-data/db-structure/parts/functions/140-planets-functions.sql

1101 lines
29 KiB
MySQL
Raw Normal View History

2018-10-23 09:38:02 +02:00
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Planet views and management functions
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
-- Planet access
CREATE TYPE planet_access_type
AS ENUM( 'BASIC' , 'PRESENT' , 'OWNER' );
-- Basic planet view
CREATE TYPE planet_basic_data AS (
access planet_access_type ,
x INT ,
y INT ,
orbit INT ,
picture INT ,
name TEXT ,
tag TEXT
);
-- Planet orbital view
CREATE TYPE planet_orbital_data AS (
population BIGINT ,
defence BIGINT ,
own_power BIGINT ,
friendly_power BIGINT ,
hostile_power BIGINT ,
battle_id BIGINT
);
-- Planet owner view
CREATE TYPE planet_owner_data AS (
happiness INT ,
h_change INT ,
income BIGINT ,
upkeep BIGINT ,
can_rename BOOLEAN ,
can_abandon BOOLEAN ,
abandon_time INT
);
-- Buildings view
CREATE TYPE planet_building_data AS (
id INT ,
name TEXT ,
description TEXT ,
amount INT ,
jobs INT ,
upkeep BIGINT ,
p_type building_output_type ,
p_value BIGINT
);
-- Build queue items
CREATE TYPE queue_item_data AS (
name TEXT ,
description TEXT ,
amount INT ,
destroy BOOLEAN ,
investment BIGINT ,
time_left BIGINT
);
-- Type for buildings available on a planet
CREATE TYPE buildable_building_data AS (
id INT ,
name TEXT ,
description TEXT ,
cost INT ,
time_to_build BIGINT ,
upkeep INT ,
workers INT ,
p_type building_output_type ,
p_value INT
);
-- Type for ships available on a planet
CREATE TYPE buildable_ship_data AS (
id INT ,
name TEXT ,
description TEXT ,
cost INT ,
time_to_build BIGINT ,
upkeep INT ,
flight_time INT ,
power INT
);
--
-- Determines an empire's access on a planet
--
-- Parameters:
-- e_id Empire identifier
-- p_id Planet identifier
--
-- Returns:
-- a basic planet view entry
--
CREATE OR REPLACE FUNCTION verse.get_planet_basics( e_id INT , p_id INT )
RETURNS planet_basic_data
STRICT STABLE
SECURITY DEFINER
AS $$
DECLARE
o_id INT;
n_flt BIGINT;
rv planet_basic_data;
BEGIN
PERFORM name_id FROM verse.planets WHERE name_id = p_id;
IF NOT FOUND THEN
RETURN NULL;
END IF;
SELECT INTO o_id ep.empire_id
FROM emp.planets ep
WHERE ep.planet_id = p_id;
SELECT INTO n_flt count( f.* )
FROM fleets.fleets f
LEFT OUTER JOIN fleets.movements fm
ON fm.fleet_id = f.id
WHERE f.location_id = p_id AND f.owner_id = e_id AND fm.fleet_id IS NULL;
IF NOT FOUND THEN
RETURN NULL;
ELSEIF o_id = e_id THEN
rv.access := 'OWNER';
ELSEIF n_flt > 0 THEN
rv.access := 'PRESENT';
ELSE
rv.access := 'BASIC';
END IF;
SELECT INTO rv.x , rv.y , rv.orbit , rv.name , rv.tag , rv.picture
x , y , orbit , name , tag , picture
FROM verse.map_view
WHERE id = p_id;
RETURN rv;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION verse.get_planet_basics( INT , INT ) TO :dbuser;
--
-- Gets a planet's orbital view from an empire's point of view
--
-- Parameters:
-- e_id Empire identifier
-- p_id Planet identifier
--
-- Returns:
-- an orbital planet view entry
--
CREATE OR REPLACE FUNCTION verse.get_orbital_view( e_id INT , p_id INT )
RETURNS planet_orbital_data
STRICT STABLE
SECURITY DEFINER
AS $$
DECLARE
rv planet_orbital_data;
2018-10-23 09:43:42 +02:00
happ DOUBLE PRECISION;
2018-10-23 09:38:02 +02:00
e_att BOOLEAN;
rec RECORD;
BEGIN
-- Get the planet's population and defence
SELECT INTO rv.population , happ
2018-10-23 09:43:42 +02:00
floor( p.population )::BIGINT , ( ph.current / p.population )::DOUBLE PRECISION
2018-10-23 09:38:02 +02:00
FROM verse.planets p
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
WHERE p.name_id = p_id;
2018-10-23 09:43:42 +02:00
rv.defence := verse.adjust_production( verse.get_raw_production( p_id , 'DEF' ) , happ );
2018-10-23 09:38:02 +02:00
-- Get the empire's fleet mode
SELECT INTO e_att f.attacking
FROM fleets.fleets f
LEFT OUTER JOIN fleets.movements fm
ON fm.fleet_id = f.id
WHERE fm.fleet_id IS NULL AND f.owner_id = p_id AND f.location_id = p_id
LIMIT 1;
IF NOT FOUND THEN
e_att := FALSE;
END IF;
-- Get fleet powers
FOR rec IN SELECT (CASE
WHEN f.owner_id = e_id THEN 'O'
WHEN f.attacking = e_att THEN 'F'
ELSE 'H'
END) AS f_type , sum( fs.amount * fsd.power ) AS power
FROM fleets.fleets f
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
INNER JOIN fleets.ships fs ON fs.fleet_id = f.id
INNER JOIN tech.ships fsd ON fsd.buildable_id = fs.ship_id
WHERE f.location_id = p_id AND m.fleet_id IS NULL
GROUP BY f.attacking , ( f.owner_id = e_id )
LOOP
IF rec.f_type = 'O' THEN
rv.own_power = rec.power;
ELSEIF rec.f_type = 'F' THEN
rv.friendly_power = rec.power;
ELSE
rv.hostile_power = rec.power;
END IF;
END LOOP;
-- Battle ID
SELECT INTO rv.battle_id id FROM battles.battles
WHERE location_id = p_id AND last_tick IS NULL;
RETURN rv;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION verse.get_orbital_view( INT , INT ) TO :dbuser;
--
-- Gets a planet's view from its owner's point of view
--
-- Parameters:
-- e_id Empire identifier
-- p_id Planet identifier
--
-- Returns:
-- an owner planet view entry
--
CREATE OR REPLACE FUNCTION verse.get_owner_view( e_id INT , p_id INT )
RETURNS planet_owner_data
STRICT STABLE
SECURITY DEFINER
AS $$
DECLARE
rv planet_owner_data;
t_happ INT;
h_chg INT;
mdelay BIGINT;
r_time INTERVAL;
BEGIN
-- Get income, upkeep, current and target happiness
SELECT INTO rv.income , rv.upkeep , rv.happiness , t_happ
floor( pm.income )::INT , floor( pm.upkeep )::INT ,
floor( 100 * ph.current / p.population )::INT ,
floor( 100 * ph.target )::INT
FROM verse.planets p
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
INNER JOIN verse.planet_money pm ON pm.planet_id = p.name_id
WHERE p.name_id = p_id;
-- Compute happiness change indicator
h_chg := t_happ - rv.happiness;
IF h_chg = 0 THEN
rv.h_change := 0;
ELSE
rv.h_change := ( CASE WHEN abs( h_chg ) > 10 THEN 2 ELSE 1 END );
IF h_chg < 0 THEN
rv.h_change := -rv.h_change;
END IF;
END IF;
-- Check whether the planet can be renamed
mdelay := floor( sys.get_constant( 'map.names.minDelay' ) * sys.get_constant( 'map.names.minDelay.units' ) )::BIGINT;
r_time := ( mdelay::BIGINT || 's' )::INTERVAL;
SELECT INTO rv.can_rename
( cmn.name_id IS NULL )
FROM naming.map_names n
LEFT OUTER JOIN naming.changed_map_names cmn
ON cmn.name_id = n.id AND cmn.named_at > now() - r_time
WHERE n.id = p_id;
-- Get abandon time
SELECT INTO rv.abandon_time time_left
FROM emp.abandon
WHERE planet_id = p_id;
IF FOUND THEN
rv.can_abandon := FALSE;
ELSE
-- Check whether the planet can be abandoned
SELECT INTO rv.can_abandon
( COUNT(ep.*) > 1 )
FROM emp.planets ep
LEFT OUTER JOIN emp.abandon a
ON a.planet_id = ep.planet_id
WHERE ep.empire_id = e_id AND a.planet_id IS NULL;
END IF;
RETURN rv;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION verse.get_owner_view( INT , INT ) TO :dbuser;
--
-- Get a planet's buildings list using an empire's language settings
--
-- Parameters:
-- e_id Empire identifier
-- p_id Planet identifier
--
-- Returns:
-- a set of buildings data entries
--
CREATE OR REPLACE FUNCTION verse.get_buildings_view( e_id INT , p_id INT )
RETURNS SETOF planet_building_data
STRICT STABLE
SECURITY DEFINER
AS $$
SELECT b.building_id AS id ,
t1.translated_string AS name , t2.translated_string AS description ,
b.amount AS amount ,
( bd.workers * b.amount )::INT AS jobs ,
( bd.upkeep * b.amount )::BIGINT AS upkeep ,
bd.output_type AS p_type ,
2018-10-23 09:43:42 +02:00
floor( verse.adjust_production( bd.output * b.amount , ph.current / p.population )
2018-10-23 09:38:02 +02:00
)::BIGINT AS p_value
FROM verse.planet_buildings b
INNER JOIN verse.planets p ON p.name_id = b.planet_id
INNER JOIN verse.planet_happiness ph ON ph.planet_id = b.planet_id
INNER JOIN tech.buildings_view bd ON bd.name_id = b.building_id
INNER JOIN naming.empire_names en ON en.id = $1
INNER JOIN users.credentials c ON c.address_id = en.owner_id
INNER JOIN defs.translations t1 ON t1.string_id = bd.name_id AND t1.lang_id = c.language_id
INNER JOIN defs.translations t2 ON t2.string_id = bd.description_id AND t2.lang_id = c.language_id
WHERE b.planet_id = $2 AND b.amount > 0
ORDER BY t1.translated_string;
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION verse.get_buildings_view( INT , INT ) TO :dbuser;
--
-- Get a planet's construction queue
--
-- Parameters:
-- p_id Planet identifier
--
-- Returns:
-- the queue's items
--
CREATE OR REPLACE FUNCTION verse.get_build_queue( p_id INT )
RETURNS SETOF queue_item_data
STRICT STABLE
SECURITY DEFINER
AS $$
SELECT t1.translated_string AS name , t2.translated_string AS description ,
qi.amount AS amount , qi.destroy AS destroy ,
( CASE
WHEN qi.destroy THEN 0
ELSE floor( qi.amount * bd.cost - ( CASE WHEN qi.queue_order = 0 THEN q.money ELSE 0 END ) )
END )::BIGINT AS investment ,
( CASE
2018-10-23 09:43:42 +02:00
WHEN ceil( verse.adjust_production( p.population * sys.get_constant( 'game.work.wuPerPopUnit' ) , ph.current / p.population ) ) = 0 THEN NULL
2018-10-23 09:38:02 +02:00
ELSE ceil( ( qi.amount * bd.work * ( CASE WHEN qi.destroy THEN sys.get_constant( 'game.work.destructionWork' ) ELSE 1 END ) - ( CASE WHEN qi.queue_order = 0 THEN q.work ELSE 0 END ) )
2018-10-23 09:43:42 +02:00
/ verse.adjust_production( p.population * sys.get_constant( 'game.work.wuPerPopUnit' ) , ph.current / p.population ) )
2018-10-23 09:38:02 +02:00
END )::BIGINT AS time_left
FROM verse.planets p
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
INNER JOIN verse.bld_queues q ON q.planet_id = p.name_id
INNER JOIN verse.bld_items qi ON qi.queue_id = q.planet_id
INNER JOIN tech.buildables bd ON bd.name_id = qi.building_id
INNER JOIN emp.planets ep ON ep.planet_id = p.name_id
INNER JOIN naming.empire_names en ON en.id = ep.empire_id
INNER JOIN users.credentials c ON c.address_id = en.owner_id
INNER JOIN defs.translations t1 ON t1.string_id = bd.name_id AND t1.lang_id = c.language_id
INNER JOIN defs.translations t2 ON t2.string_id = bd.description_id AND t2.lang_id = c.language_id
WHERE p.name_id = $1
ORDER BY qi.queue_order;
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION verse.get_build_queue( INT ) TO :dbuser;
--
-- Get a planet's military queue
--
-- Parameters:
-- p_id Planet identifier
--
-- Returns:
-- the queue's items
--
CREATE OR REPLACE FUNCTION verse.get_military_queue( p_id INT )
RETURNS SETOF queue_item_data
STRICT STABLE
SECURITY DEFINER
AS $$
SELECT t1.translated_string AS name , t2.translated_string AS description ,
qi.amount AS amount , FALSE AS destroy ,
floor( qi.amount * bd.cost - ( CASE WHEN qi.queue_order = 0 THEN q.money ELSE 0 END ) )::BIGINT AS investment ,
( CASE
2018-10-23 09:43:42 +02:00
WHEN ceil( verse.adjust_production( verse.get_raw_production( $1 , 'WORK' ) , ph.current / p.population ) ) = 0 THEN NULL
2018-10-23 09:38:02 +02:00
ELSE ceil( ( qi.amount * bd.work - ( CASE WHEN qi.queue_order = 0 THEN q.work ELSE 0 END ) )
2018-10-23 09:43:42 +02:00
/ verse.adjust_production( verse.get_raw_production( $1 , 'WORK' ) , ph.current / p.population ) )
2018-10-23 09:38:02 +02:00
END )::BIGINT AS time_left
FROM verse.planets p
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
INNER JOIN verse.mil_queues q ON q.planet_id = p.name_id
INNER JOIN verse.mil_items qi ON qi.queue_id = q.planet_id
INNER JOIN tech.buildables bd ON bd.name_id = qi.ship_id
INNER JOIN emp.planets ep ON ep.planet_id = p.name_id
INNER JOIN naming.empire_names en ON en.id = ep.empire_id
INNER JOIN users.credentials c ON c.address_id = en.owner_id
INNER JOIN defs.translations t1 ON t1.string_id = bd.name_id AND t1.lang_id = c.language_id
INNER JOIN defs.translations t2 ON t2.string_id = bd.description_id AND t2.lang_id = c.language_id
WHERE p.name_id = $1
ORDER BY qi.queue_order;
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION verse.get_military_queue( INT ) TO :dbuser;
--
-- Get the list of which buildings an empire can build on a planet
--
-- Parameters:
-- p_id Planet identifier
--
-- Returns:
-- the list of buildings
--
CREATE OR REPLACE FUNCTION verse.get_available_buildings( p_id INT )
RETURNS SETOF buildable_building_data
STRICT STABLE
SECURITY DEFINER
AS $$
SELECT bv.name_id AS id , t1.translated_string AS name , t2.translated_string AS description ,
bv.cost AS cost ,
( CASE
WHEN ceil( pdat.p_work ) = 0 THEN NULL
ELSE ceil( bv.work / pdat.p_work )
END )::BIGINT AS time_to_build ,
bv.upkeep AS upkeep , bv.workers AS workers , bv.output_type AS p_type , bv.output AS p_value
FROM (
SELECT bv.*
FROM tech.buildings_view bv
INNER JOIN tech.basic_buildables bb USING( name_id )
UNION SELECT bv.*
FROM tech.buildings_view bv
INNER JOIN tech.buildable_requirements r ON r.buildable_id = bv.name_id
2018-10-23 09:43:42 +02:00
INNER JOIN tech.technologies l ON l.name_id = r.technology_id
2018-10-23 09:38:02 +02:00
INNER JOIN emp.planets ep ON ep.planet_id = $1
2018-10-23 09:43:42 +02:00
INNER JOIN emp.researched_technologies t
ON t.empire_id = ep.empire_id AND t.technology_id = l.name_id
2018-10-23 09:38:02 +02:00
) AS bv , (
2018-10-23 09:43:42 +02:00
SELECT verse.adjust_production( p.population * sys.get_constant( 'game.work.wuPerPopUnit' ) , ph.current / p.population ) AS p_work ,
2018-10-23 09:38:02 +02:00
c.language_id AS language
FROM verse.planets p
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
INNER JOIN emp.planets ep ON ep.planet_id = p.name_id
INNER JOIN naming.empire_names en ON en.id = ep.empire_id
INNER JOIN users.credentials c ON c.address_id = en.owner_id
WHERE p.name_id = $1
) AS pdat ,
defs.translations t1 , defs.translations t2
WHERE t1.lang_id = pdat.language AND t1.string_id = bv.name_id AND t2.lang_id = pdat.language AND t2.string_id = bv.description_id
ORDER BY t1.translated_string;
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION verse.get_available_buildings( INT ) TO :dbuser;
--
-- Get the list of which ships an empire can build on a planet
--
-- Parameters:
-- p_id Planet identifier
--
-- Returns:
-- the list of ships
--
CREATE OR REPLACE FUNCTION verse.get_available_ships( p_id INT )
RETURNS SETOF buildable_ship_data
STRICT STABLE
SECURITY DEFINER
AS $$
SELECT bv.name_id AS id , t1.translated_string AS name , t2.translated_string AS description ,
bv.cost AS cost ,
( CASE
WHEN ceil( pdat.p_work ) = 0 THEN NULL
ELSE ceil( bv.work / pdat.p_work )
END )::BIGINT AS time_to_build ,
bv.upkeep AS upkeep , bv.flight_time * 2 AS flight_time , bv.power AS power
FROM (
SELECT bv.*
FROM tech.ships_view bv
INNER JOIN tech.basic_buildables bb USING( name_id )
UNION SELECT bv.*
FROM tech.ships_view bv
INNER JOIN tech.buildable_requirements r ON r.buildable_id = bv.name_id
2018-10-23 09:43:42 +02:00
INNER JOIN tech.technologies l ON l.name_id = r.technology_id
2018-10-23 09:38:02 +02:00
INNER JOIN emp.planets ep ON ep.planet_id = $1
2018-10-23 09:43:42 +02:00
INNER JOIN emp.researched_technologies t
ON t.empire_id = ep.empire_id AND t.technology_id = l.name_id
2018-10-23 09:38:02 +02:00
) AS bv , (
2018-10-23 09:43:42 +02:00
SELECT verse.adjust_production( verse.get_raw_production( $1 , 'WORK' ) , ph.current / p.population ) AS p_work ,
2018-10-23 09:38:02 +02:00
c.language_id AS language
FROM verse.planets p
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
INNER JOIN emp.planets ep ON ep.planet_id = p.name_id
INNER JOIN naming.empire_names en ON en.id = ep.empire_id
INNER JOIN users.credentials c ON c.address_id = en.owner_id
WHERE p.name_id = $1
) AS pdat ,
defs.translations t1 , defs.translations t2
WHERE t1.lang_id = pdat.language AND t1.string_id = bv.name_id AND t2.lang_id = pdat.language AND t2.string_id = bv.description_id
ORDER BY t1.translated_string;
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION verse.get_available_ships( INT ) TO :dbuser;
--
-- Rename a planet
--
-- Parameters:
-- p_id Planet identifier
-- nnm New name
--
-- Returns:
-- err_code Error code:
-- 0 Success
-- 1 Banned name
-- 2 Unavailable name
-- 3 Too early
--
CREATE OR REPLACE FUNCTION verse.rename_planet( p_id INT , nnm TEXT , OUT err_code INT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
c_id INT;
mdelay BIGINT;
BEGIN
SELECT INTO c_id n.owner_id
FROM emp.planets ep
INNER JOIN naming.empire_names n ON n.id = ep.empire_id
WHERE ep.planet_id = p_id;
mdelay := floor( sys.get_constant( 'map.names.minDelay' ) * sys.get_constant( 'map.names.minDelay.units' ) )::BIGINT;
err_code := naming.change_map_name( p_id , c_id , nnm , ( mdelay || 's' )::INTERVAL );
IF err_code = 0 THEN
PERFORM battles.rename_planet( p_id , nnm );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION verse.rename_planet( INT , TEXT ) TO :dbuser;
--
-- Flush a planet's civilian construction queue
--
-- Parameters:
-- p_id Planet identifier
--
CREATE OR REPLACE FUNCTION verse.flush_build_queue( p_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
e_id INT;
2018-10-23 09:43:42 +02:00
q_cash DOUBLE PRECISION;
2018-10-23 09:38:02 +02:00
BEGIN
SELECT INTO e_id , q_cash e.name_id , q.money
FROM verse.planets p
INNER JOIN verse.bld_queues q ON q.planet_id = p.name_id
INNER JOIN emp.planets ep ON ep.planet_id = p.name_id
INNER JOIN emp.empires e ON e.name_id = ep.empire_id
WHERE p.name_id = p_id
FOR UPDATE;
IF NOT FOUND THEN
RETURN;
END IF;
DELETE FROM verse.bld_items WHERE queue_id = p_id;
UPDATE verse.bld_queues SET money = 0 , work = 0 WHERE planet_id = p_id;
UPDATE emp.empires
SET cash = cash + q_cash * sys.get_constant('game.work.cancelRecovery')
WHERE name_id = e_id;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION verse.flush_build_queue( INT ) TO :dbuser;
--
-- Flush a planet's military construction queue
--
-- Parameters:
-- p_id Planet identifier
--
CREATE OR REPLACE FUNCTION verse.flush_military_queue( p_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
e_id INT;
2018-10-23 09:43:42 +02:00
q_cash DOUBLE PRECISION;
2018-10-23 09:38:02 +02:00
BEGIN
SELECT INTO e_id , q_cash e.name_id , q.money
FROM verse.planets p
INNER JOIN verse.mil_queues q ON q.planet_id = p.name_id
INNER JOIN emp.planets ep ON ep.planet_id = p.name_id
INNER JOIN emp.empires e ON e.name_id = ep.empire_id
WHERE p.name_id = p_id
FOR UPDATE;
IF NOT FOUND THEN
RETURN;
END IF;
DELETE FROM verse.mil_items WHERE queue_id = p_id;
UPDATE verse.mil_queues SET money = 0 , work = 0 WHERE planet_id = p_id;
UPDATE emp.empires
SET cash = cash + q_cash * sys.get_constant('game.work.cancelRecovery')
WHERE name_id = e_id;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION verse.flush_military_queue( INT ) TO :dbuser;
--
-- Adds an item to a planet's military queue
--
-- Parameters:
-- p_id Planet identifier
-- s_id Ship type identifier
-- s_cnt Amount of ships to build
--
CREATE OR REPLACE FUNCTION verse.add_military_item( p_id INT , s_id INT , s_cnt INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
e_id INT;
qlen INT;
dep_level INT;
has_level INT;
BEGIN
IF s_cnt < 1 THEN
RETURN;
END IF;
-- Lock empire and planet
SELECT INTO e_id e.name_id
FROM verse.planets p
INNER JOIN verse.mil_queues q ON q.planet_id = p.name_id
INNER JOIN emp.planets ep ON ep.planet_id = p.name_id
INNER JOIN emp.empires e ON e.name_id = ep.empire_id
WHERE p.name_id = p_id
FOR UPDATE OF p , q , ep , e;
IF NOT FOUND THEN
RETURN;
END IF;
-- Check technologies
SELECT INTO dep_level , has_level l.level , t.level
FROM tech.ships s
LEFT OUTER JOIN tech.buildable_requirements r
ON r.buildable_id = s.buildable_id
2018-10-23 09:43:42 +02:00
LEFT OUTER JOIN tech.technologies l
ON l.name_id = r.technology_id
LEFT OUTER JOIN emp.researched_technologies t
ON t.empire_id = e_id AND t.technology_id = l.name_id
2018-10-23 09:38:02 +02:00
WHERE s.buildable_id = s_id;
IF NOT FOUND OR ( has_level IS NULL AND dep_level IS NOT NULL ) THEN
RETURN;
END IF;
-- Check queue length
SELECT INTO qlen count( * ) FROM verse.mil_items WHERE queue_id = p_id;
IF qlen >= 5 THEN
RETURN;
END IF;
-- Insert queue item
INSERT INTO verse.mil_items ( queue_id , queue_order , ship_id , amount )
VALUES ( p_id , qlen , s_id , s_cnt );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION verse.add_military_item( INT , INT , INT ) TO :dbuser;
--
-- Adds building constructions to a planet's civilian queue
--
-- Parameters:
-- p_id Planet identifier
-- b_id Building type identifier
-- b_cnt Amount of ships to build
--
CREATE OR REPLACE FUNCTION verse.construct_buildings( p_id INT , b_id INT , b_cnt INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
e_id INT;
qlen INT;
dep_level INT;
has_level INT;
BEGIN
IF b_cnt < 1 THEN
RETURN;
END IF;
-- Lock empire and planet
SELECT INTO e_id e.name_id
FROM verse.planets p
INNER JOIN verse.bld_queues q ON q.planet_id = p.name_id
INNER JOIN emp.planets ep ON ep.planet_id = p.name_id
INNER JOIN emp.empires e ON e.name_id = ep.empire_id
WHERE p.name_id = p_id
FOR UPDATE OF p , q , ep , e;
IF NOT FOUND THEN
RETURN;
END IF;
-- Check technologies
SELECT INTO dep_level , has_level l.level , t.level
FROM tech.buildings b
LEFT OUTER JOIN tech.buildable_requirements r
ON r.buildable_id = b.buildable_id
2018-10-23 09:43:42 +02:00
LEFT OUTER JOIN tech.technologies l
ON l.name_id = r.technology_id
LEFT OUTER JOIN emp.researched_technologies t
ON t.empire_id = e_id AND t.technology_id = l.name_id
2018-10-23 09:38:02 +02:00
WHERE b.buildable_id = b_id;
IF NOT FOUND OR ( has_level IS NULL AND dep_level IS NOT NULL ) THEN
RETURN;
END IF;
-- Check queue length
SELECT INTO qlen count( * ) FROM verse.bld_items WHERE queue_id = p_id;
IF qlen >= 5 THEN
RETURN;
END IF;
-- Insert queue item
INSERT INTO verse.bld_items ( queue_id , queue_order , building_id , amount , destroy )
VALUES ( p_id , qlen , b_id , b_cnt , FALSE );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION verse.construct_buildings( INT , INT , INT ) TO :dbuser;
--
-- Adds building destructions to a planet's civilian queue
--
-- Parameters:
-- p_id Planet identifier
-- b_id Building type identifier
-- b_cnt Amount of ships to build
--
-- Returns:
-- success Whether the orders could be added to the queue
-- (only failures related to the amount of buildings are reported)
--
CREATE OR REPLACE FUNCTION verse.destroy_buildings( p_id INT , b_id INT , b_cnt INT , OUT success BOOLEAN )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
e_id INT;
qlen INT;
built INT;
in_queue INT;
BEGIN
IF b_cnt < 1 THEN
RETURN;
END IF;
-- Lock empire and planet
SELECT INTO e_id e.name_id
FROM verse.planets p
INNER JOIN verse.bld_queues q ON q.planet_id = p.name_id
INNER JOIN verse.planet_buildings b ON b.planet_id = p.name_id
INNER JOIN emp.planets ep ON ep.planet_id = p.name_id
INNER JOIN emp.empires e ON e.name_id = ep.empire_id
WHERE p.name_id = p_id
FOR UPDATE OF p , q , ep , e , b;
IF NOT FOUND THEN
success := TRUE;
RETURN;
END IF;
-- Check queue length
SELECT INTO qlen count( * ) FROM verse.bld_items WHERE queue_id = p_id;
IF qlen >= 5 THEN
success := TRUE;
RETURN;
END IF;
-- Check existing buildings and build queue contents
SELECT INTO built amount
FROM verse.planet_buildings
WHERE planet_id = p_id AND building_id = b_id;
IF NOT FOUND THEN
built := 0;
END IF;
SELECT INTO in_queue sum( amount * ( CASE WHEN destroy THEN -1 ELSE 1 END ) )
FROM verse.bld_items
WHERE queue_id = p_id AND building_id = b_id;
IF in_queue IS NULL THEN
in_queue := 0;
END IF;
success := ( b_cnt <= in_queue + built );
IF NOT success THEN
success := FALSE;
RETURN;
END IF;
-- Insert queue item
INSERT INTO verse.bld_items ( queue_id , queue_order , building_id , amount , destroy )
VALUES ( p_id , qlen , b_id , b_cnt , TRUE );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION verse.destroy_buildings( INT , INT , INT ) TO :dbuser;
--
-- Start abandoning a planet
--
-- Parameters:
-- p_id Planet to abandon
--
-- Returns:
-- tta Time to abandon
--
CREATE OR REPLACE FUNCTION verse.abandon( p_id INT , OUT tta INT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
PERFORM ep.planet_id
FROM emp.planets ep
INNER JOIN emp.empires e ON e.name_id = ep.empire_id
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
INNER JOIN verse.planet_money pm ON pm.planet_id = p.name_id
WHERE ep.planet_id = p_id
FOR UPDATE;
IF NOT FOUND THEN
tta := 0;
RETURN;
END IF;
tta := floor( sys.get_constant( 'game.timeToAbandon' ) );
BEGIN
INSERT INTO emp.abandon ( planet_id , time_left )
VALUES ( p_id , tta );
UPDATE verse.planet_money SET income = 0
WHERE planet_id = p_id;
EXCEPTION
WHEN unique_violation THEN
tta := 0;
END;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION verse.abandon( INT ) TO :dbuser;
--
-- Cancels planet abandon
--
-- Parameters:
-- p_id Planet not to abandon
--
CREATE OR REPLACE FUNCTION verse.cancel_abandon( p_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DELETE FROM emp.abandon WHERE planet_id = $1;
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION verse.cancel_abandon( INT ) TO :dbuser;
--
-- Prepares a planet for abandon or ownership transfer
--
-- Parameters:
-- p_id Planet identifier
--
CREATE OR REPLACE FUNCTION emp.leave_planet( p_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
bp_id BIGINT;
BEGIN
PERFORM verse.flush_military_queue( p_id );
PERFORM verse.flush_build_queue( p_id );
DELETE FROM emp.abandon WHERE planet_id = p_id;
DELETE FROM emp.planets WHERE planet_id = p_id;
-- Update battle records
SELECT INTO bp_id bpo.protagonist_id
FROM battles.battles b
INNER JOIN battles.protagonists bp ON bp.battle_id = b.id
INNER JOIN battles.planet_ownership bpo ON bpo.protagonist_id = bp.id
WHERE b.location_id = p_id AND b.last_tick IS NULL;
IF FOUND
THEN
UPDATE battles.planet_ownership
SET abandoned_at = sys.get_tick() - 1
WHERE protagonist_id = bp_id;
END IF;
END;
$$ LANGUAGE plpgsql;
--
-- Inflicts battle damage to a planet's stationary defences
--
-- Parameters:
-- p_id Planet identifier
-- t_power Total defences
-- dmg Damage to inflict
-- b_id Battle identifier
-- tick Current tick
--
2018-10-23 09:43:42 +02:00
CREATE OR REPLACE FUNCTION verse.inflict_battle_damage( p_id INT , t_power BIGINT , dmg DOUBLE PRECISION , b_id BIGINT , tick BIGINT )
2018-10-23 09:38:02 +02:00
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
rec RECORD;
bp_id BIGINT;
2018-10-23 09:43:42 +02:00
st_dmg DOUBLE PRECISION;
2018-10-23 09:38:02 +02:00
n_dest INT;
BEGIN
PERFORM sys.write_log( 'BattleUpdate' , 'TRACE'::log_level , 'Inflicting ' || dmg
|| ' damage to planet #' || p_id );
bp_id := NULL;
FOR rec IN SELECT b.building_id , b.amount , b.damage , ( b.amount * bd.output ) AS power ,
bd.output AS s_power
FROM verse.planet_buildings b
INNER JOIN tech.buildings bd ON bd.buildable_id = b.building_id
WHERE b.planet_id = p_id AND b.amount > 0 AND bd.output_type = 'DEF'
LOOP
st_dmg := rec.damage + ( dmg * rec.power / t_power ) / rec.s_power;
n_dest := floor( st_dmg );
st_dmg := st_dmg - n_dest;
IF n_dest >= rec.amount THEN
n_dest := rec.amount;
st_dmg := 0;
END IF;
PERFORM sys.write_log( 'BattleUpdate' , 'TRACE'::log_level , 'Building type #' || rec.building_id
|| ' - Damage ' || st_dmg || '; destruction: ' || n_dest );
-- Apply damage
UPDATE verse.planet_buildings
SET damage = st_dmg , amount = amount - n_dest
WHERE planet_id = p_id AND building_id = rec.building_id;
-- Update battle record
CONTINUE WHEN n_dest = 0;
IF bp_id IS NULL THEN
bp_id := battles.goc_planet( b_id , 'BATTLE'::battle_planet_change , tick );
END IF;
PERFORM battles.record_building_change( bp_id , rec.building_id , -n_dest );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Inflicts debt-related damage to all buildings of an empire
--
-- Parameters:
-- e_id Empire identifer
-- t_upkeep Total building upkeep
-- debt Daily debt
-- d_ratio Debt damage ratio
--
2018-10-23 09:43:42 +02:00
CREATE OR REPLACE FUNCTION verse.handle_debt( e_id INT , t_upkeep DOUBLE PRECISION , debt DOUBLE PRECISION , d_ratio DOUBLE PRECISION )
2018-10-23 09:38:02 +02:00
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
tick BIGINT;
2018-10-23 09:43:42 +02:00
tot_damage DOUBLE PRECISION;
2018-10-23 09:38:02 +02:00
p_rec RECORD;
b_rec RECORD;
bp_id BIGINT;
2018-10-23 09:43:42 +02:00
b_damage DOUBLE PRECISION;
2018-10-23 09:38:02 +02:00
n_destroy 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 buildings; total upkeep: '
|| t_upkeep || ', damage ratio: ' || d_ratio || ', total damage: ' || tot_damage );
FOR p_rec IN SELECT ep.planet_id AS planet , b.id AS battle
FROM emp.planets ep
LEFT OUTER JOIN battles.battles b
ON b.location_id = ep.planet_id AND b.last_tick IS NULL
WHERE ep.empire_id = e_id
LOOP
bp_id := NULL;
FOR b_rec IN SELECT b.building_id AS building , b.amount AS amount ,
2018-10-23 09:43:42 +02:00
b.amount * bb.upkeep AS upkeep ,
2018-10-23 09:38:02 +02:00
b.damage AS damage , ( bd.output_type = 'DEF' ) AS is_def
FROM verse.planet_buildings b
INNER JOIN tech.buildables bb ON bb.name_id = b.building_id
INNER JOIN tech.buildings bd ON bd.buildable_id = b.building_id
WHERE b.amount > 0 AND b.planet_id = p_rec.planet
LOOP
-- Compute damage and destruction
b_damage := b_rec.damage + tot_damage * b_rec.upkeep / t_upkeep;
n_destroy := floor( b_damage );
IF n_destroy >= b_rec.amount
THEN
n_destroy := b_rec.amount;
b_damage := 0;
ELSE
b_damage := b_damage - n_destroy;
END IF;
-- Update entry
UPDATE verse.planet_buildings
SET amount = amount - n_destroy , damage = b_damage
WHERE building_id = b_rec.building AND planet_id = p_rec.planet;
-- Update battle
CONTINUE WHEN p_rec.battle IS NULL OR NOT b_rec.is_def OR n_destroy = 0;
IF bp_id IS NULL
THEN
bp_id := battles.goc_planet( p_rec.battle , 'DESTROY'::battle_planet_change , tick );
END IF;
PERFORM battles.record_building_change( bp_id , b_rec.building , -n_destroy );
END LOOP;
END LOOP;
END;
2018-10-23 09:43:42 +02:00
$$ LANGUAGE plpgsql;