Database definition & tests organisation

* The main loader script has been updated to generate the list of files
it needs to load automatically. As a consequence, files that contained
manually-maintained lists of scripts have been removed, and definition
directories have been renamed accordingly.

* PostgreSQL extension loading and configuration has been moved to a
separate script to be loaded automatically in the main transaction.

* Data and function definition scripts that had the -data or -functions
suffix have been renamed (the suffix is unnecessary).

* Unit tests have been reorganised to follow the definition's structure.

* Documentation has been improved
This commit is contained in:
Emmanuel BENOîT 2012-01-06 11:19:19 +01:00
parent b054a379a9
commit e50775ec76
112 changed files with 78 additions and 144 deletions

View file

@ -0,0 +1,172 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - control functions
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- Start a tick
--
CREATE OR REPLACE FUNCTION sys.start_tick( OUT tick_id BIGINT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
n_tick BIGINT;
c_tick BIGINT;
BEGIN
-- Get next / current tick
SELECT INTO n_tick , c_tick next_tick , current_tick
FROM sys.status
WHERE maintenance_start IS NULL
FOR UPDATE;
IF NOT FOUND OR c_tick IS NOT NULL THEN
tick_id := NULL;
RETURN;
END IF;
-- Prepare game updates
UPDATE sys.updates SET last_tick = n_tick , status = 'FUTURE'
WHERE last_tick < n_tick;
-- Update system status
UPDATE sys.status SET current_tick = n_tick , next_tick = n_tick + 1;
tick_id := n_tick;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.start_tick( ) TO :dbuser;
--
-- Marks a tick as completed
--
CREATE OR REPLACE FUNCTION sys.end_tick( IN tick_id BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
BEGIN
UPDATE events.events SET status = 'READY'
WHERE status = 'TICK' AND tick = tick_id;
UPDATE sys.status SET current_tick = NULL;
PERFORM msgs.deliver_internal( );
END;
$$ LANGUAGE plpgsql;
--
-- Check if a tick got "stuck"
--
CREATE OR REPLACE FUNCTION sys.check_stuck_tick( OUT tick_id BIGINT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
c_tick BIGINT;
u_count INT;
BEGIN
-- Get next / current tick
SELECT INTO c_tick current_tick
FROM sys.status
WHERE maintenance_start IS NULL
FOR UPDATE;
IF NOT FOUND OR c_tick IS NULL THEN
tick_id := NULL;
RETURN;
END IF;
-- Are there any updates left?
SELECT INTO u_count count(*) FROM sys.updates
WHERE status = 'FUTURE' AND last_tick = c_tick;
IF u_count = 0 THEN
PERFORM sys.end_tick( c_tick );
tick_id := NULL;
ELSE
tick_id := c_tick;
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.check_stuck_tick( ) TO :dbuser;
--
-- Process game updates
--
-- Parameters:
-- c_tick Current tick
--
-- Returns:
-- TRUE if the function must be called again, FALSE otherwise
--
CREATE OR REPLACE FUNCTION sys.process_updates( IN c_tick BIGINT , OUT has_more BOOLEAN )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
b_size INT;
p_utype update_type;
utype update_type;
uid BIGINT;
BEGIN
b_size := sys.get_constant( 'game.batchSize' );
p_utype := NULL;
-- Mark at most b_size entries as being updated
FOR uid , utype IN SELECT id , gu_type FROM sys.updates
WHERE last_tick = c_tick AND status = 'FUTURE'
ORDER BY gu_type LIMIT b_size
LOOP
IF p_utype IS NULL THEN
p_utype := utype;
END IF;
EXIT WHEN utype <> p_utype;
UPDATE sys.updates SET status = 'PROCESSING' WHERE id = uid;
END LOOP;
has_more := p_utype IS NOT NULL;
IF has_more THEN
-- Execute actual updates
EXECUTE 'SELECT sys.process_' || lower( p_utype::TEXT ) || '_updates( $1 )'
USING c_tick;
UPDATE sys.updates SET status = 'PROCESSED'
WHERE status = 'PROCESSING' AND last_tick = c_tick;
ELSE
-- If nothing was found, we're done
PERFORM sys.end_tick( c_tick );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION sys.process_updates( BIGINT ) TO :dbuser;

View file

@ -0,0 +1,81 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - empire money
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
CREATE OR REPLACE FUNCTION sys.process_empire_money_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
rec RECORD;
c_cash REAL;
c_debt REAL;
BEGIN
-- Lock empires for update
PERFORM e.name_id FROM sys.updates su
INNER JOIN emp.updates eu
ON eu.update_id = su.id
INNER JOIN emp.empires e
ON eu.empire_id = e.name_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'EMPIRE_MONEY'
FOR UPDATE OF e;
-- Select all money-related data from empires being updated
FOR rec IN SELECT e.name_id AS id , e.cash AS cash , e.debt AS debt ,
( pov.planet_income - pov.planet_upkeep ) AS p_money ,
fov.fleet_upkeep AS f_money , ( v.status = 'PROCESSED' ) AS on_vacation
FROM sys.updates su
INNER JOIN emp.updates eu ON eu.update_id = su.id
INNER JOIN emp.empires e ON eu.empire_id = e.name_id
INNER JOIN emp.fleets_overview fov ON fov.empire = e.name_id
INNER JOIN emp.planets_overview pov ON pov.empire = e.name_id
INNER JOIN naming.empire_names en ON en.id = e.name_id
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'EMPIRE_MONEY'
LOOP
-- Compute new cash reserve
c_cash := 0;
IF rec.p_money IS NOT NULL THEN
c_cash := c_cash + rec.p_money;
END IF;
IF rec.f_money IS NOT NULL THEN
c_cash := c_cash - rec.f_money;
END IF;
-- Effects of vacation mode
IF rec.on_vacation
THEN
c_cash := c_cash / sys.get_constant( 'vacation.cashDivider' );
END IF;
-- Handle debt
c_cash := rec.cash + c_cash / 1440.0;
IF c_cash < 0 THEN
c_debt := -c_cash;
c_cash := 0;
ELSE
c_debt := 0;
END IF;
IF rec.debt > 0 AND c_debt = 0
THEN
PERFORM events.debt_event( rec.id , FALSE );
ELSEIF rec.debt = 0 AND c_debt > 0
THEN
PERFORM events.debt_event( rec.id , TRUE );
END IF;
-- Update empire
UPDATE emp.empires SET cash = c_cash , debt = c_debt
WHERE name_id = rec.id;
END LOOP;
END;
$$ LANGUAGE plpgsql;

View file

@ -0,0 +1,86 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - empire research
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
CREATE OR REPLACE FUNCTION sys.process_empire_research_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
rec RECORD;
r_points REAL;
tu_rec RECORD;
BEGIN
-- Lock empires for update and planets for share
PERFORM e.name_id FROM sys.updates su
INNER JOIN emp.updates eu ON eu.update_id = su.id
INNER JOIN emp.empires e ON eu.empire_id = e.name_id
INNER JOIN emp.planets ep ON ep.empire_id = e.name_id
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'EMPIRE_RESEARCH'
FOR UPDATE OF e
FOR SHARE OF ep , p;
-- Process empires
FOR rec IN SELECT e.name_id AS id , ( v.status = 'PROCESSED' ) AS on_vacation ,
sum( p.population ) AS population
FROM sys.updates su
INNER JOIN emp.updates eu ON eu.update_id = su.id
INNER JOIN emp.empires e ON eu.empire_id = e.name_id
INNER JOIN emp.planets ep ON ep.empire_id = e.name_id
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
INNER JOIN naming.empire_names en ON en.id = e.name_id
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'EMPIRE_RESEARCH'
GROUP BY e.name_id , v.status
LOOP
-- Insert any missing tech line
INSERT INTO emp.technologies ( empire_id , line_id )
SELECT rec.id , l.name_id
FROM tech.lines l
LEFT OUTER JOIN emp.technologies t
ON t.line_id = l.name_id AND t.empire_id = rec.id
WHERE t.empire_id IS NULL;
-- Compute research output
r_points := rec.population * sys.get_constant( 'game.work.rpPerPopUnit' ) / 1440.0;
IF rec.on_vacation
THEN
r_points := r_points / sys.get_constant( 'vacation.researchDivider' );
END IF;
-- Update technologies where:
-- 1) the level actually exists and
-- 2) accumulated points haven't reach the level's
FOR tu_rec IN SELECT t.line_id AS line_id , t.accumulated AS accumulated ,
l.points AS points , ( l.points - t.accumulated ) AS diff ,
l.id AS level_id
FROM emp.technologies t
INNER JOIN tech.levels l ON l.line_id = t.line_id
AND l.level = t.level AND t.accumulated < l.points
WHERE t.empire_id = rec.id
FOR UPDATE OF t
LOOP
UPDATE emp.technologies t SET accumulated = ( CASE
WHEN tu_rec.diff <= r_points THEN tu_rec.points
ELSE tu_rec.accumulated + r_points
END )
WHERE t.line_id = tu_rec.line_id AND t.empire_id = rec.id;
-- Send message
IF tu_rec.diff <= r_points
THEN
PERFORM events.tech_ready_event( rec.id , tu_rec.level_id );
END IF;
END LOOP;
END LOOP;
END;
$$ LANGUAGE plpgsql;

View file

@ -0,0 +1,62 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - damage fleets and buildings when an
-- empire is out of cash and has too much upkeep
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
CREATE OR REPLACE FUNCTION sys.process_empire_debt_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
fleet_dr REAL;
bld_dr REAL;
empire INT;
debt REAL;
upkeep REAL;
BEGIN
fleet_dr := sys.get_constant( 'game.debt.fleet');
bld_dr := sys.get_constant( 'game.debt.buildings');
FOR empire, debt IN SELECT e.name_id AS id , e.debt
FROM sys.updates su
INNER JOIN emp.updates eu ON eu.update_id = su.id
INNER JOIN emp.empires e ON eu.empire_id = e.name_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'EMPIRE_DEBT' AND e.debt > 0
FOR UPDATE
LOOP
PERFORM sys.write_log( 'EmpireDebt' , 'DEBUG'::log_level , 'Handling debt for empire #'
|| empire || ' (at tick: ' || debt || '; daily: ' || ( debt * 1440 ) || ')' );
debt := debt * 1440.0;
-- Does the empire own fleets?
SELECT INTO upkeep sum( d.upkeep * s.amount )
FROM fleets.fleets f
INNER JOIN fleets.ships s ON s.fleet_id = f.id
INNER JOIN tech.buildables d ON d.name_id = s.ship_id
WHERE f.owner_id = empire;
IF upkeep IS NOT NULL
THEN
PERFORM fleets.handle_debt( empire , upkeep , ( CASE WHEN debt > upkeep THEN upkeep ELSE debt END ) , fleet_dr );
debt := debt - upkeep;
CONTINUE WHEN debt <= 0;
END IF;
-- Does the empire have buildings?
SELECT INTO upkeep sum( d.upkeep * b.amount )
FROM emp.planets ep
INNER JOIN verse.planet_buildings b ON b.planet_id = ep.planet_id
INNER JOIN tech.buildables d ON d.name_id = b.building_id
WHERE ep.empire_id = empire;
CONTINUE WHEN NOT FOUND OR upkeep = 0;
PERFORM verse.handle_debt( empire , upkeep , debt , bld_dr );
END LOOP;
END;
$$ LANGUAGE plpgsql;

View file

@ -0,0 +1,148 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - fleet arrivals
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
CREATE OR REPLACE FUNCTION sys.process_planet_fleet_arrivals_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
rec RECORD;
lstat BOOLEAN;
f_ids BIGINT[];
BEGIN
-- Lock all records
PERFORM f.id FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
INNER JOIN emp.empires e ON e.name_id = f.owner_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_ARRIVALS'
AND f.status = 'AVAILABLE' AND fm.time_left = 1
FOR UPDATE;
-- Update attack status according to planet owners and enemy lists
FOR rec IN SELECT ep.empire_id AS planet_owner , p.name_id AS planet ,
f.owner_id AS fleet_owner , ( v.status = 'PROCESSED' AND b.id IS NULL ) AS on_vacation ,
bool_or( f.attacking ) AS attacking
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
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
LEFT OUTER JOIN battles.battles b
ON b.location_id = p.name_id AND b.last_tick IS NULL
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_ARRIVALS'
AND f.status = 'AVAILABLE' AND fm.time_left = 1
GROUP BY p.name_id , ep.empire_id , f.owner_id , v.status , b.id
LOOP
-- Fleets owned by the planet's owner are never attacking, same for fleets arriving on
-- planets that are on vacation
IF rec.fleet_owner = rec.planet_owner OR rec.on_vacation THEN
UPDATE fleets.fleets f SET attacking = FALSE
FROM fleets.movements m
WHERE f.status = 'AVAILABLE' AND f.owner_id = rec.fleet_owner
AND f.location_id = rec.planet AND m.fleet_id = f.id AND m.time_left = 1;
CONTINUE;
END IF;
-- Check enemy lists
PERFORM * FROM emp.enemies
WHERE empire = rec.planet_owner AND enemy = rec.fleet_owner;
IF FOUND
THEN
-- Fleet owner in the planet owner's EL
UPDATE fleets.fleets f SET attacking = TRUE
FROM fleets.movements m
WHERE f.status = 'AVAILABLE' AND f.owner_id = rec.fleet_owner
AND f.location_id = rec.planet AND m.fleet_id = f.id AND m.time_left = 1;
CONTINUE;
END IF;
-- If one of the arriving fleets is attacking, or if the local fleets are already attacking,
-- then switch all local or arriving fleets to attack
SELECT INTO lstat f.attacking
FROM fleets.fleets f
LEFT OUTER JOIN fleets.movements fm ON fm.fleet_id = f.id
WHERE f.owner_id = rec.fleet_owner AND f.location_id = rec.planet AND fm IS NULL
GROUP BY f.attacking;
IF ( FOUND AND lstat ) OR rec.attacking
THEN
SELECT INTO f_ids array_agg( f.id ) FROM fleets.fleets f
WHERE f.owner_id = rec.fleet_owner AND f.location_id = rec.planet;
PERFORM fleets.set_mode( rec.fleet_owner , f_ids , TRUE );
CONTINUE;
END IF;
END LOOP;
-- Prepare fleet arrival events
CREATE TEMPORARY TABLE fleet_arrivals(
loc_id INT ,
loc_name VARCHAR(20) ,
own_id INT ,
own_name VARCHAR(20) ,
name VARCHAR(64) ,
power BIGINT ,
mode BOOLEAN ,
src_id INT ,
src_name VARCHAR(20)
);
INSERT INTO fleet_arrivals
SELECT f.location_id , ln.name , f.owner_id , fon.name ,
f.name , fs.power , f.attacking , fm.source_id , sn.name
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
INNER JOIN fleets.stats_view fs ON fs.id = f.id
INNER JOIN naming.empire_names fon ON fon.id = f.owner_id
INNER JOIN naming.map_names ln ON ln.id = f.location_id
INNER JOIN naming.map_names sn ON sn.id = fm.source_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_ARRIVALS'
AND f.status = 'AVAILABLE' AND fm.time_left = 1;
-- Delete movement records, set redeployment penalties, update battles
FOR rec IN SELECT f.id AS fleet , fs.flight_time AS flight_time ,
f.attacking AS attacking , b.id AS battle ,
f.location_id AS location
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
INNER JOIN fleets.stats_view fs ON fs.id = f.id
LEFT OUTER JOIN battles.battles b
ON b.location_id = p.name_id AND b.last_tick IS NULL
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_ARRIVALS'
AND f.status = 'AVAILABLE' AND fm.time_left = 1
LOOP
DELETE FROM fleets.movements
WHERE fleet_id = rec.fleet;
UPDATE fleets.fleets
SET status = 'REDEPLOYING' ,
penalty = 1 + rec.flight_time * ( CASE WHEN rec.attacking THEN 40 ELSE 10 END )
WHERE id = rec.fleet;
-- Add fleets to battle (will not be executed if battle is NULL)
PERFORM battles.add_fleet( rec.battle , rec.fleet , FALSE , c_tick );
END LOOP;
-- Send fleet arrival events
PERFORM events.commit_fleet_arrivals( c_tick );
END;
$$ LANGUAGE plpgsql;

View file

@ -0,0 +1,110 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - fleet movements
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
CREATE OR REPLACE FUNCTION sys.process_planet_fleet_movements_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
rec RECORD;
rpid INT;
BEGIN
-- Lock all records
PERFORM f.id FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
INNER JOIN emp.empires e ON e.name_id = f.owner_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_MOVEMENTS'
AND f.status = 'AVAILABLE'
FOR UPDATE;
-- Handle state transitions
FOR rec IN SELECT f.id AS id , max( fsd.flight_time ) AS flight_time ,
s.x AS x , s.y AS y , s.id AS sys_id ,
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 ,
rps.x AS is_ref_point_x , rps.y AS is_ref_point_y
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN verse.systems s ON s.id = p.system_id
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
INNER JOIN fleets.ships fs ON fs.fleet_id = f.id
INNER JOIN tech.ships fsd ON fsd.buildable_id = fs.ship_id
INNER JOIN fleets.movements m ON m.fleet_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
LEFT OUTER JOIN verse.systems rps ON rps.id = rp.system_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_MOVEMENTS'
AND f.status = 'AVAILABLE' AND m.state_time_left = 1
GROUP BY f.id , s.x , s.y , s.id , isms.ref_point_id , isms.outwards ,
isms.past_ref_point , rp.system_id , rp.orbit , rps.x , rps.y
LOOP
IF rec.is_ref_point_orbit IS NOT NULL THEN
IF rec.is_ref_point_orbit = 5 AND rec.is_outwards AND rec.is_past_ref_point THEN
-- Fleet exiting system
INSERT INTO fleets.ms_space ( movement_id , start_x , start_y )
VALUES ( rec.id , rec.is_ref_point_x , rec.is_ref_point_y );
DELETE FROM fleets.ms_system WHERE movement_id = rec.id;
UPDATE fleets.movements
SET state_time_left = 1 + fleets.compute_outerspace_duration(
rec.flight_time , rec.is_ref_point_x , rec.is_ref_point_y , rec.x , rec.y )
WHERE fleet_id = rec.id;
ELSE
-- In-system state change
IF rec.is_past_ref_point THEN
SELECT INTO rpid p.name_id FROM verse.planets p
WHERE p.system_id = rec.is_ref_point_system
AND p.orbit = rec.is_ref_point_orbit + ( CASE WHEN rec.is_outwards THEN 1 ELSE -1 END );
UPDATE fleets.ms_system
SET past_ref_point = FALSE , ref_point_id = rpid
WHERE movement_id = rec.id;
ELSE
UPDATE fleets.ms_system SET past_ref_point = TRUE
WHERE movement_id = rec.id;
END IF;
UPDATE fleets.movements
SET state_time_left = rec.flight_time + 1
WHERE fleet_id = rec.id;
END IF;
ELSE
-- Fleet entering system
SELECT INTO rpid p.name_id FROM verse.planets p
WHERE p.system_id = rec.sys_id AND p.orbit = 5;
INSERT INTO fleets.ms_system ( movement_id , ref_point_id , outwards , past_ref_point )
VALUES ( rec.id , rpid , FALSE , FALSE );
DELETE FROM fleets.ms_space WHERE movement_id = rec.id;
UPDATE fleets.movements
SET state_time_left = rec.flight_time + 1
WHERE fleet_id = rec.id;
END IF;
END LOOP;
-- Decrease movement and state time
UPDATE fleets.movements
SET state_time_left = state_time_left - 1 ,
time_left = time_left - 1
WHERE fleet_id IN (
SELECT f.id FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
INNER JOIN fleets.movements fm ON fm.fleet_id = f.id
INNER JOIN emp.empires e ON e.name_id = f.owner_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_MOVEMENTS'
AND f.status = 'AVAILABLE' );
END;
$$ LANGUAGE plpgsql;

View file

@ -0,0 +1,77 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - fleet status
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
CREATE OR REPLACE FUNCTION sys.process_planet_fleet_status_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
rec RECORD;
mt_id BIGINT;
BEGIN
-- Lock all records
PERFORM f.id FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN fleets.fleets f ON f.location_id = p.name_id
INNER JOIN emp.empires e ON e.name_id = f.owner_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_STATUS'
FOR UPDATE;
-- Fleet deployments
FOR rec IN SELECT f.id AS fleet , f.owner_id AS owner , f.location_id AS location ,
b.id AS battle
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN fleets.fleets f ON f.location_id = vu.planet_id
AND f.status = 'DEPLOYING' AND f.penalty = 1
INNER JOIN emp.empires e ON e.name_id = f.owner_id
LEFT OUTER JOIN battles.battles b
ON b.location_id = f.location_id AND b.last_tick IS NULL
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_STATUS'
LOOP
-- Add fleet to battle (will be ignored if battle is NULL)
PERFORM battles.add_fleet( rec.battle , rec.fleet , TRUE , c_tick );
-- Find the biggest available fleet belonging to that owner
SELECT INTO mt_id f.id
FROM fleets.fleets f
INNER JOIN fleets.ships s ON s.fleet_id = f.id
INNER JOIN tech.ships sd ON sd.buildable_id = s.ship_id
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id
WHERE f.owner_id = rec.owner AND f.location_id = rec.location
AND m.fleet_id IS NULL AND f.status = 'AVAILABLE'
GROUP BY f.id
ORDER BY sum( sd.power * s.amount ) DESC
LIMIT 1;
CONTINUE WHEN NOT FOUND;
-- Merge fleet
PERFORM fleets.merge_ships( mt_id , rec.fleet );
DELETE FROM fleets.fleets WHERE id = rec.fleet;
END LOOP;
-- Fleets that must become available
UPDATE fleets.fleets f SET status = 'AVAILABLE' , penalty = 0
FROM sys.updates su , verse.updates vu
WHERE vu.update_id = su.id AND f.location_id = vu.planet_id
AND f.penalty = 1 AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_STATUS' AND su.last_tick = c_tick;
-- Fleets that still have a penalty
UPDATE fleets.fleets f SET penalty = penalty - 1
FROM sys.updates su , verse.updates vu
WHERE vu.update_id = su.id AND f.location_id = vu.planet_id
AND f.penalty > 1 AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_FLEET_STATUS' AND su.last_tick = c_tick;
END;
$$ LANGUAGE plpgsql;

View file

@ -0,0 +1,181 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - battles (start, main computation, end)
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
CREATE OR REPLACE FUNCTION sys.process_planet_battle_start_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
p_id INT;
BEGIN
FOR p_id IN SELECT p.name_id
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
LEFT OUTER JOIN battles.battles b
ON b.location_id = p.name_id AND b.last_tick IS NULL
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_BATTLE_START' AND b.location_id IS NULL
FOR UPDATE OF p
LOOP
IF battles.check_start( p_id ) THEN
PERFORM events.battle_start_event( battles.initialise( p_id , c_tick ) );
END IF;
END LOOP;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION sys.process_planet_battle_main_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
ttfi INT;
initi REAL;
dbonus REAL;
dmg REAL;
rdmg REAL;
rec RECORD;
a_power BIGINT;
d_power BIGINT;
p_power BIGINT;
bmod REAL;
a_dmg REAL;
d_dmg REAL;
BEGIN
ttfi := floor( sys.get_constant( 'game.battle.timeToFullIntensity' ) )::INT;
initi := sys.get_constant( 'game.battle.initialIntensity' );
dbonus := sys.get_constant( 'game.battle.defenceBonus');
dmg := sys.get_constant( 'game.battle.damage' );
rdmg := sys.get_constant( 'game.battle.randomDamage' );
FOR rec IN SELECT b.id AS battle , b.first_tick AS first_tick ,
b.location_id AS location , ( ph.current / p.population )::REAL AS happiness
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
INNER JOIN battles.battles b
ON b.location_id = p.name_id AND b.last_tick IS NULL
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_BATTLE_MAIN'
FOR UPDATE OF p , b
LOOP
PERFORM sys.write_log( 'BattleUpdate' , 'DEBUG'::log_level , 'Handling battle #' || rec.battle
|| ' at planet #' || rec.location );
-- Get stationary defence power
p_power := floor( verse.adjust_production( verse.get_raw_production( rec.location , 'DEF' ) , rec.happiness ) );
-- Get fleets power
a_power := battles.get_fleets_power( rec.battle , c_tick , TRUE );
d_power := battles.get_fleets_power( rec.battle , c_tick , FALSE );
IF a_power = 0 OR d_power + p_power = 0
THEN
PERFORM battles.set_defence_power( rec.battle , c_tick , p_power );
CONTINUE;
END IF;
PERFORM sys.write_log( 'BattleUpdate' , 'TRACE'::log_level , 'Attack: ' || a_power
|| '; planetary defences: ' || p_power || '; defence: ' || d_power );
-- Compute battle intensity
IF c_tick - rec.first_tick < ttfi THEN
bmod := initi + ( 1 - initi ) * ( c_tick - rec.first_tick ) / ttfi;
ELSE
bmod := 1.0;
END IF;
PERFORM sys.write_log( 'BattleUpdate' , 'TRACE'::log_level , 'Intensity modifier: ' || bmod );
-- Compute damage
d_dmg := bmod * ( d_power * ( 1 + dbonus ) + p_power ) * dmg * ( 1 - rdmg + 2.0 * rdmg * random() );
a_dmg := bmod * a_power * dmg * ( 1 - rdmg + 2.0 * rdmg * random() );
PERFORM sys.write_log( 'BattleUpdate' , 'TRACE'::log_level , 'Damage - to defence: ' || a_dmg
|| '; to attack: ' || d_dmg );
-- Inflict damage
PERFORM battles.inflict_damage( rec.battle , a_dmg , FALSE , c_tick );
PERFORM battles.inflict_damage( rec.battle , d_dmg , TRUE , c_tick );
-- Update defence power
p_power := floor( verse.adjust_production( verse.get_raw_production( rec.location , 'DEF' ) , rec.happiness ) );
PERFORM battles.set_defence_power( rec.battle , c_tick , p_power );
END LOOP;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION sys.process_planet_battle_end_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
rec RECORD;
n_owner INT;
BEGIN
FOR rec IN SELECT b.id AS battle , b.location_id AS location
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
INNER JOIN battles.battles b
ON b.location_id = p.name_id AND b.last_tick IS NULL
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_BATTLE_END'
FOR UPDATE OF p , b
LOOP
IF battles.get_fleets_power( rec.battle , c_tick , TRUE ) = 0 THEN
-- Attack is dead/gone, end the battle
UPDATE battles.battles SET last_tick = c_tick
WHERE id = rec.battle;
PERFORM events.battle_end_event( rec.battle );
ELSEIF battles.get_fleets_power( rec.battle , c_tick , FALSE ) + battles.get_defence_power( rec.battle , c_tick ) = 0 THEN
-- Defence is dead/gone, transfer planet ownership to biggest fleet owner
n_owner := battles.get_biggest_fleet_owner( rec.battle , c_tick );
PERFORM events.planet_ochange_events( rec.location , n_owner );
PERFORM emp.leave_planet( rec.location );
INSERT INTO emp.planets( planet_id , empire_id )
VALUES( rec.location , n_owner );
-- End the battle
UPDATE battles.battles SET last_tick = c_tick
WHERE id = rec.battle;
PERFORM events.battle_end_event( rec.battle );
-- Set fleets in orbit to defence if they're not on the new owner's enemy list
UPDATE fleets.fleets f SET attacking = ( ele.empire IS NOT NULL )
FROM fleets.fleets f2
LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f2.id
LEFT OUTER JOIN emp.enemies ele ON ele.enemy = f2.owner_id AND ele.empire = n_owner
WHERE f.id = f2.id AND f.location_id = rec.location AND m.fleet_id IS NULL;
-- Check if the battle needs to be restarted
IF battles.check_start( rec.location ) THEN
PERFORM events.battle_start_event( battles.initialise( rec.location , c_tick ) );
END IF;
ELSE
CONTINUE;
END IF;
-- Mark the end of the battle
INSERT INTO battles.finished_battles_list
SELECT empire, battle, planet, x, y, orbit, name, first_tick, last_tick, last_update
FROM battles.full_battles_list
WHERE battle = rec.battle;
END LOOP;
END;
$$ LANGUAGE plpgsql;

View file

@ -0,0 +1,48 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - abandon
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
CREATE OR REPLACE FUNCTION sys.process_planet_abandon_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
p_id INT;
BEGIN
-- Lock all records
PERFORM p.name_id FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN emp.planets ep ON p.name_id = vu.planet_id
INNER JOIN emp.empires e ON e.name_id = ep.empire_id
INNER JOIN emp.abandon a ON a.planet_id = p.name_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_ABANDON'
FOR UPDATE;
-- Handle planets where time has run out
FOR p_id IN SELECT p.name_id
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON p.name_id = vu.planet_id
INNER JOIN emp.abandon a ON a.planet_id = p.name_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_ABANDON' AND a.time_left = 1
LOOP
PERFORM emp.leave_planet( p_id );
END LOOP;
-- Update all abandon records
UPDATE emp.abandon a SET time_left = a.time_left - 1
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_ABANDON' AND a.planet_id = vu.planet_id;
END;
$$ LANGUAGE plpgsql;

View file

@ -0,0 +1,217 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - buildings construction and destruction
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
CREATE OR REPLACE FUNCTION sys.process_planet_construction_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
rec RECORD;
wu_per_pop REAL;
dest_work REAL;
dest_rec REAL;
cur_empire INT;
cur_cash REAL;
cur_planet INT;
p_finished BOOLEAN;
cur_wus REAL;
cur_acc_c REAL;
n_found INT;
n_removed INT;
i_work REAL;
i_cost REAL;
can_do REAL;
must_do INT;
BEGIN
-- Get constants
wu_per_pop := sys.get_constant( 'game.work.wuPerPopUnit' );
dest_work := sys.get_constant( 'game.work.destructionWork' );
dest_rec := - sys.get_constant( 'game.work.destructionRecovery' );
-- Enter update loop
cur_empire := NULL;
cur_planet := NULL;
FOR rec IN SELECT p.name_id AS id , p.population AS pop ,
( ph.current / p.population )::REAL AS happiness ,
e.name_id AS owner , e.cash AS cash ,
q.money AS acc_cash , q.work AS acc_work ,
qi.queue_order AS qorder , qi.amount AS amount ,
qi.destroy AS destroy , qi.building_id AS building ,
b.work AS req_work , b.cost AS req_cost
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON vu.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
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 b ON b.name_id = qi.building_id
INNER JOIN naming.empire_names en ON en.id = e.name_id
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_CONSTRUCTION'
AND ( v.account_id IS NULL OR v.status <> 'PROCESSED' )
ORDER BY e.name_id , p.name_id , qi.queue_order
FOR UPDATE OF p , e , q , qi
LOOP
-- Update accumulated work and money for the previous planet
IF cur_planet IS NOT NULL AND cur_planet <> rec.id THEN
IF n_found = n_removed THEN
cur_wus := 0;
cur_acc_c := 0;
PERFORM events.empty_queue_events( cur_empire , cur_planet , FALSE , c_tick );
END IF;
UPDATE verse.bld_queues
SET money = cur_acc_c , work = cur_wus
WHERE planet_id = cur_planet;
cur_cash := cur_cash - cur_acc_c;
IF cur_cash < 0 THEN
cur_cash := 0;
END IF;
cur_planet := NULL;
END IF;
-- Update cash of the previous empire
IF cur_empire IS NOT NULL AND cur_empire <> rec.owner
THEN
UPDATE emp.empires SET cash = cur_cash
WHERE name_id = cur_empire;
cur_empire := NULL;
END IF;
-- If this is the first record or if the empire changed...
IF cur_empire IS NULL THEN
cur_empire := rec.owner;
cur_cash := rec.cash;
END IF;
-- If this is the first record or if the planet changed...
IF cur_planet IS NULL THEN
cur_planet := rec.id;
cur_cash := cur_cash + rec.acc_cash;
cur_wus := rec.acc_work + verse.adjust_production(
( rec.pop * wu_per_pop )::REAL ,
rec.happiness
);
n_found := 1;
n_removed := 0;
cur_acc_c := 0;
p_finished := FALSE;
ELSE
n_found := n_found + 1;
END IF;
-- If we're done updating this planet but there were more items...
IF p_finished THEN
IF n_removed > 0 THEN
UPDATE verse.bld_items
SET queue_order = rec.qorder - n_removed
WHERE queue_order = rec.qorder AND queue_id = rec.id;
END IF;
CONTINUE;
END IF;
-- Compute the actual cost and required work of the item
i_cost := rec.req_cost * ( CASE WHEN rec.destroy THEN dest_rec ELSE 1.0 END );
i_work := rec.req_work * ( CASE WHEN rec.destroy THEN dest_work ELSE 1.0 END );
-- Compute how many items can be completed
can_do := cur_wus / i_work;
IF i_cost > 0 AND cur_cash / i_cost < can_do THEN
can_do := cur_cash / i_cost;
cur_wus := i_work * can_do;
END IF;
-- If we can't build anything at this point...
IF can_do < 1 THEN
-- Set accumulated cash
IF i_cost > 0 THEN
cur_acc_c := can_do * i_cost;
END IF;
-- Still update queue item if some items were removed
IF n_removed > 0 THEN
UPDATE verse.bld_items
SET queue_order = rec.qorder - n_removed
WHERE queue_order = rec.qorder AND queue_id = rec.id;
END IF;
-- Done with this planet
p_finished := TRUE;
CONTINUE;
END IF;
-- Compute how many actual items can be built
must_do := floor( can_do );
IF must_do >= rec.amount THEN
must_do := rec.amount;
can_do := 0;
n_removed := n_removed + 1;
END IF;
-- Handle construction / destruction
IF rec.destroy THEN
must_do := verse.do_destroy_buildings( rec.id , rec.building , must_do );
PERFORM battles.remove_buildings( rec.id , rec.building , must_do , FALSE , c_tick + 1 );
ELSE
PERFORM verse.do_construct_buildings( rec.id , rec.building , must_do );
PERFORM battles.add_buildings( rec.id , rec.building , must_do , c_tick + 1 );
END IF;
cur_cash := cur_cash - must_do * i_cost;
cur_wus := cur_wus - must_do * i_work;
-- Check whether we're done with this queue
IF rec.qorder < n_removed THEN
-- Delete queue item
DELETE FROM verse.bld_items
WHERE queue_order = rec.qorder AND queue_id = rec.id;
ELSE
-- Update queue item
UPDATE verse.bld_items
SET queue_order = queue_order - n_removed ,
amount = amount - floor( can_do )
WHERE queue_order = rec.qorder AND queue_id = rec.id;
-- Set accumulated cash
IF i_cost > 0 THEN
cur_acc_c := ( can_do - floor( can_do ) ) * i_cost;
END IF;
p_finished := TRUE;
END IF;
END LOOP;
-- If a planet was being procesed, update it and the empire
IF cur_planet IS NOT NULL THEN
IF n_found = n_removed THEN
cur_wus := 0;
cur_acc_c := 0;
PERFORM events.empty_queue_events( cur_empire , cur_planet , FALSE , c_tick );
END IF;
UPDATE verse.bld_queues
SET money = cur_acc_c , work = cur_wus
WHERE planet_id = cur_planet;
cur_cash := cur_cash - cur_acc_c;
IF cur_cash < 0 THEN
cur_cash := 0;
END IF;
UPDATE emp.empires SET cash = cur_cash
WHERE name_id = cur_empire;
cur_empire := NULL;
END IF;
END;
$$ LANGUAGE plpgsql;

View file

@ -0,0 +1,227 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - ship construction
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
CREATE OR REPLACE FUNCTION sys.process_planet_military_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
rec RECORD;
cur_empire INT;
cur_cash REAL;
cur_planet INT;
p_finished BOOLEAN;
cur_wus REAL;
cur_acc_c REAL;
n_found INT;
n_removed INT;
can_do REAL;
must_do INT;
fl_id BIGINT;
BEGIN
-- Create temporary table for built ships
CREATE TEMPORARY TABLE blt_ships(
location INT ,
owner INT ,
ship INT ,
amount INT
);
-- Enter update loop
cur_empire := NULL;
cur_planet := NULL;
FOR rec IN SELECT p.name_id AS id ,
( ph.current / p.population )::REAL AS happiness ,
e.name_id AS owner , e.cash AS cash ,
q.money AS acc_cash , q.work AS acc_work ,
qi.queue_order AS qorder , qi.amount AS amount ,
qi.ship_id AS ship , s.work AS req_work , s.cost AS req_cost
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON vu.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
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 s ON s.name_id = qi.ship_id
INNER JOIN naming.empire_names en ON en.id = e.name_id
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_MILITARY'
AND ( v.account_id IS NULL OR v.status <> 'PROCESSED' )
ORDER BY e.name_id , p.name_id , qi.queue_order
FOR UPDATE OF p , e , q , qi
LOOP
-- Update accumulated work and money for the previous planet
IF cur_planet IS NOT NULL AND cur_planet <> rec.id THEN
IF n_found = n_removed THEN
cur_wus := 0;
cur_acc_c := 0;
PERFORM events.empty_queue_events( cur_empire , cur_planet , TRUE , c_tick );
END IF;
UPDATE verse.mil_queues
SET money = cur_acc_c , work = cur_wus
WHERE planet_id = cur_planet;
cur_cash := cur_cash - cur_acc_c;
IF cur_cash < 0 THEN
cur_cash := 0;
END IF;
cur_planet := NULL;
END IF;
-- Update cash of the previous empire
IF cur_empire IS NOT NULL AND cur_empire <> rec.owner
THEN
UPDATE emp.empires SET cash = cur_cash
WHERE name_id = cur_empire;
cur_empire := NULL;
END IF;
-- If this is the first record or if the empire changed...
IF cur_empire IS NULL THEN
cur_empire := rec.owner;
cur_cash := rec.cash;
END IF;
-- If this is the first record or if the planet changed...
IF cur_planet IS NULL THEN
cur_planet := rec.id;
cur_cash := cur_cash + rec.acc_cash;
cur_wus := rec.acc_work + verse.adjust_production(
verse.get_raw_production( rec.id , 'WORK' ) ,
rec.happiness
);
n_found := 1;
n_removed := 0;
cur_acc_c := 0;
p_finished := FALSE;
ELSE
n_found := n_found + 1;
END IF;
-- If we're done updating this planet but there were more items...
IF p_finished THEN
IF n_removed > 0 THEN
UPDATE verse.mil_items
SET queue_order = rec.qorder - n_removed
WHERE queue_order = rec.qorder AND queue_id = rec.id;
END IF;
CONTINUE;
END IF;
-- Compute how many items can be completed
can_do := cur_wus / rec.req_work;
IF cur_cash / rec.req_cost < can_do THEN
can_do := cur_cash / rec.req_cost;
cur_wus := rec.req_work * can_do;
END IF;
-- If we can't build anything at this point...
IF can_do < 1 THEN
-- Set accumulated cash
cur_acc_c := can_do * rec.req_cost;
-- Still update queue item if some items were removed
IF n_removed > 0 THEN
UPDATE verse.mil_items
SET queue_order = rec.qorder - n_removed
WHERE queue_order = rec.qorder AND queue_id = rec.id;
END IF;
-- Done with this planet
p_finished := TRUE;
CONTINUE;
END IF;
-- Compute how many actual items can be built
must_do := floor( can_do );
IF must_do >= rec.amount THEN
must_do := rec.amount;
can_do := 0;
n_removed := n_removed + 1;
END IF;
-- Handle construction
INSERT INTO blt_ships( location , owner , ship , amount)
VALUES ( rec.id , rec.owner , rec.ship , must_do );
cur_cash := cur_cash - must_do * rec.req_cost;
cur_wus := cur_wus - must_do * rec.req_work;
-- Check whether we're done with this queue
IF rec.qorder < n_removed THEN
-- Delete queue item
DELETE FROM verse.mil_items
WHERE queue_order = rec.qorder AND queue_id = rec.id;
ELSE
-- Update queue item
UPDATE verse.mil_items
SET queue_order = queue_order - n_removed ,
amount = amount - must_do
WHERE queue_order = rec.qorder AND queue_id = rec.id;
-- Set accumulated cash
cur_acc_c := ( can_do - floor( can_do ) ) * rec.req_cost;
p_finished := TRUE;
END IF;
END LOOP;
-- If a planet was being procesed, update it and the empire
IF cur_planet IS NOT NULL THEN
IF n_found = n_removed THEN
cur_wus := 0;
cur_acc_c := 0;
PERFORM events.empty_queue_events( cur_empire , cur_planet , TRUE , c_tick );
END IF;
UPDATE verse.mil_queues
SET money = cur_acc_c , work = cur_wus
WHERE planet_id = cur_planet;
cur_cash := cur_cash - cur_acc_c;
IF cur_cash < 0 THEN
cur_cash := 0;
END IF;
UPDATE emp.empires SET cash = cur_cash
WHERE name_id = cur_empire;
cur_empire := NULL;
END IF;
-- Spawn fleets
FOR cur_planet , cur_empire IN SELECT DISTINCT location , owner FROM blt_ships
LOOP
-- Get fleet's flight time
SELECT INTO must_do MAX( s.flight_time )
FROM blt_ships b
INNER JOIN tech.ships s ON s.buildable_id = b.ship
WHERE b.location = cur_planet AND b.owner = cur_empire;
-- Insert the fleet
INSERT INTO fleets.fleets (owner_id, location_id , attacking , status , penalty )
VALUES ( cur_empire , cur_planet , FALSE , 'DEPLOYING' , must_do * 2 )
RETURNING id INTO fl_id;
-- Insert ships
INSERT INTO fleets.ships ( fleet_id , ship_id , amount , damage )
SELECT fl_id , b.ship , sum( b.amount ) , 0
FROM blt_ships b
WHERE b.location = cur_planet AND b.owner = cur_empire
GROUP BY b.ship;
END LOOP;
-- Destroy temporary table
DROP TABLE blt_ships;
END;
$$ LANGUAGE plpgsql;

View file

@ -0,0 +1,104 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - population growth and happiness
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
CREATE OR REPLACE FUNCTION sys.process_planet_population_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
rec RECORD;
rel_ch REAL;
abs_ch REAL;
g_fact REAL;
gf_inc REAL;
n_happ REAL;
t_happ REAL;
temp REAL;
growth REAL;
workers REAL;
str_thr REAL;
BEGIN
-- Get constants
rel_ch := sys.get_constant( 'game.happiness.relativeChange' );
abs_ch := sys.get_constant( 'game.happiness.maxAbsoluteChange' );
g_fact := sys.get_constant( 'game.growthFactor' );
gf_inc := sys.get_constant( 'game.growthFactor.rCentre' );
str_thr := sys.get_constant( 'game.happiness.strike' );
-- Process planets
FOR rec IN SELECT p.name_id AS id , p.population AS pop ,
ph.target AS target , ph.current AS happy_pop ,
( ph.current / p.population )::REAL AS current
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_POPULATION'
FOR UPDATE OF p, ph
LOOP
IF round( rec.target / rel_ch ) = round( rec.current / rel_ch ) THEN
-- Happiness does not change
n_happ := rec.current;
ELSE
-- Compute new happiness
temp := rec.pop * rel_ch;
IF temp > abs_ch THEN
temp := abs_ch;
ELSEIF temp < 1 THEN
temp := 1;
END IF;
IF rec.target < rec.current THEN
temp := - temp;
END IF;
n_happ := ( rec.happy_pop + temp ) / rec.pop;
END IF;
-- Compute population growth
temp := verse.adjust_production( verse.get_raw_production( rec.id , 'POP' ) , n_happ );
growth := ( g_fact + temp * gf_inc ) * n_happ / 1440.0;
-- Get workers
SELECT INTO workers SUM( b.amount * d.workers )
FROM verse.planet_buildings b
INNER JOIN tech.buildings d
ON d.buildable_id = b.building_id
WHERE b.planet_id = rec.id;
IF workers IS NULL THEN
workers := 0;
END IF;
-- Compute new target happiness
t_happ := verse.compute_happiness( rec.pop + growth , workers ,
verse.adjust_production( verse.get_raw_production( rec.id , 'DEF' ) , n_happ ) ,
emp.get_size( rec.id )
);
-- Update planet and happiness records
UPDATE verse.planet_happiness
SET current = ( rec.pop + growth ) * n_happ , target = t_happ
WHERE planet_id = rec.id;
UPDATE verse.planets
SET population = rec.pop + growth
WHERE name_id = rec.id;
-- Send strike begin/end messages
IF n_happ < str_thr AND rec.current >= str_thr
THEN
PERFORM events.strike_event( rec.id , TRUE );
ELSEIF n_happ >= str_thr AND rec.current < str_thr
THEN
PERFORM events.strike_event( rec.id , FALSE );
END IF;
END LOOP;
END;
$$ LANGUAGE plpgsql;

View file

@ -0,0 +1,47 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - resource regeneration
--
-- Copyright(C) 2004-2012, DeepClone Development
-- --------------------------------------------------------
/*
* Resource provider regeneration update
*
* This function computes the regeneration of resource providers for the current batch
* of planets.
*
* Parameters:
* _tick The identifier of the game update
*/
CREATE OR REPLACE FUNCTION sys.process_planet_res_regen_updates( _tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $process_planet_res_regen_updates$
UPDATE verse.resource_providers _provider
SET resprov_quantity = verse.compute_provider_regeneration(
_provider.resprov_quantity ,
_provider.resprov_quantity_max ,
_provider.resprov_recovery
)
FROM sys.updates _upd_sys
INNER JOIN verse.updates _upd_verse
ON _upd_verse.update_id = _upd_sys.id
WHERE _upd_sys.last_tick = $1
AND _upd_sys.status = 'PROCESSING'
AND _upd_sys.gu_type = 'PLANET_RES_REGEN'
AND _provider.planet_id = _upd_verse.planet_id;
$process_planet_res_regen_updates$ LANGUAGE SQL;
REVOKE EXECUTE
ON FUNCTION sys.process_planet_res_regen_updates( BIGINT )
FROM PUBLIC;

View file

@ -0,0 +1,45 @@
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - planet income and upkeep
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
CREATE OR REPLACE FUNCTION sys.process_planet_money_updates( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
rec RECORD;
incme REAL;
BEGIN
FOR rec IN SELECT p.name_id AS id , p.population AS pop ,
( ph.current / p.population )::REAL AS happiness ,
( ea.planet_id IS NULL ) AS produces_income
FROM sys.updates su
INNER JOIN verse.updates vu ON vu.update_id = su.id
INNER JOIN verse.planets p ON vu.planet_id = p.name_id
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
LEFT OUTER JOIN emp.abandon ea ON ea.planet_id = p.name_id
WHERE su.last_tick = c_tick AND su.status = 'PROCESSING'
AND su.gu_type = 'PLANET_MONEY'
FOR UPDATE OF p, pm
LOOP
IF rec.produces_income THEN
incme := verse.compute_income( rec.pop , rec.happiness ,
verse.get_raw_production( rec.id , 'CASH' )
);
ELSE
incme := 0;
END IF;
UPDATE verse.planet_money
SET income = incme ,
upkeep = verse.get_planet_upkeep( rec.id )
WHERE planet_id = rec.id;
END LOOP;
END;
$$ LANGUAGE plpgsql;