-- LegacyWorlds Beta 6 -- PostgreSQL database scripts -- -- Empire management functions and views -- -- Copyright(C) 2004-2011, DeepClone Development -- -------------------------------------------------------- -- -- Empire creation -- -- Parameters: -- nid Empire name identifier -- pid Planet identifier -- icash Initial cash -- CREATE OR REPLACE FUNCTION emp.create_empire( nid INT , pid INT , icash DOUBLE PRECISION ) RETURNS VOID STRICT VOLATILE SECURITY INVOKER AS $$ DECLARE uid BIGINT; utp update_type; BEGIN -- Add empire and give initial planet INSERT INTO emp.empires ( name_id , cash ) VALUES ( nid , icash ); INSERT INTO emp.planets ( planet_id , empire_id ) VALUES ( pid , nid ); -- Add empire update records FOR utp IN SELECT x FROM unnest( enum_range( NULL::update_type ) ) AS x WHERE x::text LIKE 'EMPIRE_%' LOOP INSERT INTO sys.updates( gu_type ) VALUES ( utp ) RETURNING id INTO uid; INSERT INTO emp.updates ( update_id , empire_id ) VALUES ( uid , nid ); END LOOP; END; $$ LANGUAGE plpgsql; -- -- Returns a planet owner's empire size -- CREATE OR REPLACE FUNCTION emp.get_size( pid INT ) RETURNS INT STRICT STABLE SECURITY INVOKER AS $$ SELECT count( aep.* )::INT FROM emp.planets ep INNER JOIN emp.planets aep ON ep.empire_id = aep.empire_id WHERE ep.planet_id = $1; $$ LANGUAGE SQL; -- -- Returns the empire associated with an account -- CREATE OR REPLACE FUNCTION emp.get_current( a_id INT , OUT empire_id INT ) STRICT STABLE SECURITY DEFINER AS $$ SELECT e.name_id AS empire_id FROM users.credentials c INNER JOIN naming.empire_names en ON en.owner_id = c.address_id INNER JOIN emp.empires e ON e.name_id = en.id WHERE c.address_id = $1; $$ LANGUAGE SQL; GRANT EXECUTE ON FUNCTION emp.get_current( INT ) TO :dbuser; -- -- Add an enemy empire -- -- Parameters: -- e_id Empire identifier -- e_name New enemy name -- -- Returns: -- err_code Error code: -- 0 on success -- 1 if the specified empire does not exist -- 2 if the player is being schizophrenic -- 3 if the enemy list already contains the specified empire -- CREATE OR REPLACE FUNCTION emp.add_enemy_empire( e_id INT , e_name TEXT , OUT err_code INT ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE en_id INT; BEGIN SELECT INTO en_id e.name_id FROM emp.empires e INNER JOIN naming.empire_names en ON e.name_id = en.id WHERE lower( en.name ) = lower( e_name ); IF NOT FOUND THEN err_code := 1; ELSEIF en_id = e_id THEN err_code := 2; ELSE BEGIN INSERT INTO emp.enemy_empires (empire_id , enemy_id) VALUES (e_id , en_id); err_code := 0; EXCEPTION WHEN unique_violation THEN err_code := 3; END; END IF; IF err_code = 0 THEN PERFORM emp.switch_enemies( e_id ); END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION emp.add_enemy_empire( INT , TEXT ) TO :dbuser; -- -- Add an enemy alliance -- -- Parameters: -- e_id Empire identifier -- e_name Alliance tag -- -- Returns: -- err_code Error code: -- 0 on success -- 1 if the specified alliance does not exist -- 2 if the player is adding his/her own alliance -- 3 if the enemy list already contains the specified alliance -- CREATE OR REPLACE FUNCTION emp.add_enemy_alliance( e_id INT , e_name TEXT , OUT err_code INT ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE en_id INT; e_ca_id INT; BEGIN SELECT INTO en_id a.id FROM emp.alliances a WHERE lower( a.tag ) = lower( e_name ); IF NOT FOUND THEN err_code := 1; ELSE SELECT INTO e_ca_id ea.alliance_id FROM emp.alliance_members ea WHERE ea.empire_id = e_id; IF FOUND AND en_id = e_ca_id THEN err_code := 2; ELSE BEGIN INSERT INTO emp.enemy_alliances (empire_id , alliance_id) VALUES (e_id , en_id); err_code := 0; EXCEPTION WHEN unique_violation THEN err_code := 3; END; END IF; END IF; IF err_code = 0 THEN PERFORM emp.switch_enemies( e_id ); END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION emp.add_enemy_alliance( INT , TEXT ) TO :dbuser; -- -- Remove enemy empires -- -- Parameters: -- e_id Empire identifier -- rem_ids Identifiers of enemy empires to remove -- CREATE OR REPLACE FUNCTION emp.remove_enemy_empires( e_id INT , rem_ids INT[]) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ BEGIN DELETE FROM emp.enemy_empires WHERE empire_id = e_id AND enemy_id IN ( SELECT unnest( rem_ids ) AS id ); END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION emp.remove_enemy_empires( INT , INT[] ) TO :dbuser; -- -- Remove enemy alliances -- -- Parameters: -- e_id Empire identifier -- rem_ids Identifiers of enemy alliances to remove -- CREATE OR REPLACE FUNCTION emp.remove_enemy_alliances( e_id INT , rem_ids INT[]) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ BEGIN DELETE FROM emp.enemy_alliances WHERE empire_id = e_id AND alliance_id IN ( SELECT unnest( rem_ids ) AS id ); END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION emp.remove_enemy_alliances( INT , INT[] ) TO :dbuser; -- -- Switch enemies to attack -- -- Parameters: -- e_id Empire identifier -- CREATE OR REPLACE FUNCTION emp.switch_enemies( e_id INT ) RETURNS VOID STRICT VOLATILE SECURITY INVOKER AS $$ DECLARE rec RECORD; BEGIN 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; INSERT INTO fleet_switches SELECT f.location_id , ln.name , f.owner_id , fon.name , f.name , fs.power , TRUE FROM fleets.fleets f INNER JOIN emp.planets ep ON f.location_id = ep.planet_id INNER JOIN verse.planets p ON p.name_id = ep.planet_id INNER JOIN emp.enemies el ON el.enemy = f.owner_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 ep.empire_id = e_id AND el.empire = e_id AND m.fleet_id IS NULL AND NOT f.attacking; PERFORM events.commit_fleet_switches( TRUE ); FOR rec IN SELECT DISTINCT f.location_id AS location , f.owner_id AS owner , b.id AS battle FROM fleets.fleets f INNER JOIN emp.planets ep ON f.location_id = ep.planet_id INNER JOIN verse.planets p ON p.name_id = ep.planet_id INNER JOIN emp.enemies el ON el.enemy = f.owner_id LEFT OUTER JOIN fleets.movements m ON m.fleet_id = f.id 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 AND el.empire = e_id AND m.fleet_id IS NULL AND NOT f.attacking LOOP -- Set fleets mode UPDATE fleets.fleets f SET attacking = TRUE , status = 'REDEPLOYING' , penalty = ( CASE WHEN f2.penalty > ( 1 + fs.flight_time * 40 ) THEN f2.penalty ELSE ( 1 + fs.flight_time * 40 ) 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 = rec.owner 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 , rec.owner , TRUE ); END LOOP; PERFORM msgs.deliver_internal( ); END; $$ LANGUAGE plpgsql; -- -- Deletes an empire -- CREATE OR REPLACE FUNCTION emp.delete_empire( e_id INT ) RETURNS VOID STRICT VOLATILE SECURITY INVOKER AS $$ DECLARE p_id INT; f_id BIGINT; fleets BIGINT[]; BEGIN -- Lock empire PERFORM * FROM emp.empires WHERE name_id = e_id FOR UPDATE; -- Disband fleets fleets := '{}'::BIGINT[]; FOR f_id IN SELECT id FROM fleets.fleets WHERE owner_id = e_id FOR UPDATE LOOP fleets := array_append( fleets , f_id ); END LOOP; PERFORM fleets.disband( e_id , fleets ); -- Abandon planets FOR p_id IN SELECT planet_id FROM emp.planets WHERE empire_id = e_id LOOP PERFORM emp.leave_planet( p_id ); END LOOP; -- Leave alliance PERFORM emp.leave_alliance( e_id ); -- Delete empire DELETE FROM emp.empires WHERE name_id = e_id; END; $$ LANGUAGE plpgsql; -- -- Obtains a new planet -- -- Parameters: -- e_id Empire identifier -- p_name Planet name -- -- Returns: -- err_code Error code: -- 0 success -- 1 banned name -- 2 name unavailable -- 3 empire has planets -- CREATE OR REPLACE FUNCTION emp.get_new_planet( e_id INT , p_name TEXT , OUT err_code INT ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE plid INT; accid INT; ccash DOUBLE PRECISION; f_id BIGINT; fleets BIGINT[]; BEGIN -- Lock empire and check for existing planets SELECT INTO ccash cash FROM emp.empires WHERE name_id = e_id FOR UPDATE; PERFORM * FROM emp.planets WHERE empire_id = e_id LIMIT 1; IF FOUND THEN err_code := 3; RETURN; END IF; SELECT INTO accid owner_id FROM naming.empire_names WHERE id = e_id; -- Get random planet and rename it plid := verse.get_random_planet( ); IF plid IS NULL THEN err_code := 2; ELSE err_code := - naming.change_map_name( plid , accid , p_name ); END IF; IF err_code <> 0 THEN RETURN; END IF; INSERT INTO emp.planets ( planet_id , empire_id ) VALUES ( plid , e_id ); -- Disband fleets fleets := '{}'::BIGINT[]; FOR f_id IN SELECT id FROM fleets.fleets WHERE owner_id = e_id FOR UPDATE LOOP fleets := array_append( fleets , f_id ); END LOOP; PERFORM fleets.disband( e_id , fleets ); -- Reset to initial cash if below IF ccash < sys.get_constant( 'game.initialCash' ) THEN UPDATE emp.empires SET cash = sys.get_constant( 'game.initialCash' ) WHERE name_id = e_id; END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION emp.get_new_planet( INT , TEXT ) TO :dbuser; -- -- Enemies view -- CREATE VIEW emp.enemies AS SELECT iq.empire AS empire , iq.enemy AS enemy FROM ( SELECT ee.empire_id AS empire , ee.enemy_id AS enemy FROM emp.enemy_empires ee UNION SELECT ea.empire_id AS empire , am.empire_id AS enemy FROM emp.enemy_alliances ea INNER JOIN emp.alliance_members am ON am.alliance_id = ea.alliance_id AND NOT am.is_pending ) AS iq ORDER BY iq.empire , iq.enemy; -- -- General information view -- CREATE VIEW emp.general_information AS SELECT e.name_id AS id , en.name AS name , av.language , ( CASE WHEN av.status = 'QUITTING' THEN 'q' WHEN av.status = 'VACATION' THEN 'v' WHEN av.status = 'START_VACATION' THEN 's' ELSE NULL END ) AS status , e.cash AS cash , a.tag AS alliance , st.next_tick AS game_time , av.id AS account_id FROM emp.empires e INNER JOIN naming.empire_names en ON en.id = e.name_id INNER JOIN users.accounts_view av ON av.id = en.owner_id LEFT OUTER JOIN emp.alliance_members am ON am.empire_id = e.name_id AND NOT am.is_pending LEFT OUTER JOIN emp.alliances a ON a.id = am.alliance_id CROSS JOIN sys.status st; GRANT SELECT ON emp.general_information TO :dbuser; -- -- Empire planets view -- CREATE VIEW emp.planets_view AS SELECT e.empire_id AS empire , n.id AS id , n.name AS name FROM emp.planets e INNER JOIN verse.planets p ON p.name_id = e.planet_id INNER JOIN verse.systems s ON s.id = p.system_id INNER JOIN naming.map_names n ON n.id = e.planet_id ORDER BY e.empire_id , s.x , s.y , p.orbit; GRANT SELECT ON emp.planets_view TO :dbuser; -- -- Empire overviews -- CREATE VIEW emp.planets_overview AS SELECT e.name_id AS empire , count( p.* ) AS planets , sum( floor( p.population) ) AS population , floor( avg( 100.0 * ph.current / p.population ) ) AS avg_happiness , floor( sum( pm.income ) ) AS planet_income , floor( sum( pm.upkeep ) ) AS planet_upkeep FROM emp.empires e LEFT OUTER JOIN emp.planets ep ON ep.empire_id = e.name_id LEFT OUTER JOIN verse.planets p ON p.name_id = ep.planet_id LEFT OUTER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id LEFT OUTER JOIN verse.planet_money pm ON pm.planet_id = p.name_id GROUP BY e.name_id; CREATE VIEW emp.civ_invest_acc_totals AS SELECT e.name_id AS empire , sum( cq.money ) AS acc_total FROM emp.empires e LEFT OUTER JOIN emp.planets ep ON ep.empire_id = e.name_id LEFT OUTER JOIN verse.bld_queues cq ON cq.planet_id = ep.planet_id GROUP BY e.name_id; CREATE VIEW emp.civ_investment_view AS SELECT e.name_id AS empire , ( sum( bqi.amount * bqid.cost ) - ( CASE WHEN ciat.acc_total IS NULL THEN 0 ELSE ciat.acc_total END ) )::BIGINT AS civ_investment FROM emp.empires e LEFT OUTER JOIN emp.planets ep ON ep.empire_id = e.name_id LEFT OUTER JOIN emp.civ_invest_acc_totals ciat ON ciat.empire = e.name_id LEFT OUTER JOIN verse.bld_items bqi ON bqi.queue_id = ep.planet_id AND NOT bqi.destroy LEFT OUTER JOIN tech.buildables bqid ON bqid.name_id = bqi.building_id GROUP BY e.name_id, ciat.acc_total; CREATE VIEW emp.mil_invest_acc_totals AS SELECT e.name_id AS empire , sum( mq.money ) AS acc_total FROM emp.empires e LEFT OUTER JOIN emp.planets ep ON ep.empire_id = e.name_id LEFT OUTER JOIN verse.mil_queues mq ON mq.planet_id = ep.planet_id GROUP BY e.name_id; CREATE VIEW emp.mil_investment_view AS SELECT e.name_id AS empire , ( sum( mqi.amount * mqid.cost ) - ( CASE WHEN miat.acc_total IS NULL THEN 0 ELSE miat.acc_total END ) )::BIGINT AS mil_investment FROM emp.empires e LEFT OUTER JOIN emp.planets ep ON ep.empire_id = e.name_id LEFT OUTER JOIN emp.mil_invest_acc_totals miat ON miat.empire = e.name_id LEFT OUTER JOIN verse.mil_items mqi ON mqi.queue_id = ep.planet_id LEFT OUTER JOIN tech.buildables mqid ON mqid.name_id = mqi.ship_id GROUP BY e.name_id, miat.acc_total; CREATE VIEW emp.fleets_overview AS SELECT e.name_id AS empire , sum( sd.power * s.amount ) AS fleet_power , sum( sbd.upkeep * s.amount ) AS fleet_upkeep FROM emp.empires e LEFT OUTER JOIN fleets.fleets f ON f.owner_id = e.name_id LEFT OUTER JOIN fleets.ships s ON s.fleet_id = f.id LEFT OUTER JOIN tech.ships sd ON sd.buildable_id = s.ship_id LEFT OUTER JOIN tech.buildables sbd ON sbd.name_id = sd.buildable_id GROUP BY e.name_id; CREATE VIEW emp.new_messages AS SELECT e.name_id AS empire , count( m.* ) AS new_messages FROM emp.empires e LEFT OUTER JOIN msgs.empire_delivery m ON m.empire_id = e.name_id AND m.in_inbox AND m.status = 'UNREAD' GROUP BY e.name_id; CREATE VIEW emp.overview AS SELECT * FROM emp.planets_overview INNER JOIN emp.fleets_overview USING (empire) INNER JOIN emp.civ_investment_view USING (empire) INNER JOIN emp.mil_investment_view USING (empire) INNER JOIN emp.new_messages USING (empire); GRANT SELECT ON emp.overview TO :dbuser; -- -- Enemy lists -- CREATE VIEW emp.enemy_lists AS SELECT x.empire AS empire , x.id AS id , x.name AS name , x.alliance AS alliance FROM ( SELECT el.empire_id AS empire , el.enemy_id AS id , n.name AS name , FALSE AS alliance FROM emp.enemy_empires el INNER JOIN naming.empire_names n ON n.id = el.enemy_id UNION SELECT el.empire_id AS empire , el.alliance_id AS id , a.tag AS name , TRUE AS alliance FROM emp.enemy_alliances el INNER JOIN emp.alliances a ON a.id = el.alliance_id ) AS x; GRANT SELECT ON emp.enemy_lists TO :dbuser;