-- LegacyWorlds Beta 6 -- PostgreSQL database scripts -- -- Universe management functions and views -- -- Copyright(C) 2004-2010, DeepClone Development -- -------------------------------------------------------- -- -- Obtains a planet's raw production -- -- Parameters: -- pid Planet identifier -- pt Production type -- -- Returns: -- the planet's raw production of the specified type -- CREATE OR REPLACE FUNCTION verse.get_raw_production( pid INT , pt building_output_type ) RETURNS REAL STRICT STABLE SECURITY DEFINER AS $$ DECLARE rv REAL; BEGIN SELECT INTO rv SUM( b.amount * d.output )::REAL FROM verse.planet_buildings b INNER JOIN tech.buildings d ON d.buildable_id = b.building_id AND d.output_type = pt WHERE b.planet_id = pid; IF rv IS NULL THEN rv := 0; END IF; RETURN rv; END; $$ LANGUAGE plpgsql; -- -- Map view -- CREATE VIEW verse.map_view AS SELECT s.x AS x , s.y AS y , p.orbit AS orbit , n.id AS id , p.picture AS picture , n.name AS name , ep.empire_id AS owner , a.id AS alliance_id , a.tag AS tag FROM verse.planets p INNER JOIN verse.systems s ON s.id = p.system_id INNER JOIN naming.map_names n ON n.id = p.name_id LEFT OUTER JOIN emp.planets ep ON ep.planet_id = p.name_id LEFT OUTER JOIN emp.alliance_members am ON ep.empire_id = am.empire_id AND NOT am.is_pending LEFT OUTER JOIN emp.alliances a ON a.id = am.alliance_id ORDER BY s.x , s.y , p.orbit; -- -- View of planets that can be assigned to players -- CREATE VIEW verse.available_planets AS SELECT p.name_id AS name_id FROM verse.planets p INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id LEFT OUTER JOIN emp.planets ep ON ep.planet_id = p.name_id LEFT OUTER JOIN fleets.fleets f ON f.location_id = p.name_id WHERE ep.empire_id IS NULL AND ph.target > 0.5 AND verse.get_raw_production( p.name_id , 'DEF'::building_output_type ) > 0 AND verse.get_raw_production( p.name_id , 'WORK'::building_output_type ) > 0 AND ph.current / p.population > sys.get_constant( 'game.happiness.strike' ) GROUP BY p.name_id HAVING count(f.*) = 0; -- -- Returns a random free planet, locked for update -- CREATE OR REPLACE FUNCTION verse.get_random_planet( ) RETURNS INT STRICT VOLATILE SECURITY INVOKER AS $$ SELECT name_id FROM verse.planets p INNER JOIN verse.available_planets USING ( name_id ) ORDER BY random() LIMIT 1 FOR UPDATE OF p; $$ LANGUAGE SQL; -- -- Obtains a planet's upkeep -- -- Parameters: -- pid Planet identifier -- -- Returns: -- the planet's current upkeep -- CREATE OR REPLACE FUNCTION verse.get_planet_upkeep( pid INT ) RETURNS REAL STRICT STABLE SECURITY INVOKER AS $$ DECLARE rv REAL; BEGIN SELECT INTO rv SUM( b.amount * d.upkeep )::REAL FROM verse.planet_buildings b INNER JOIN tech.buildables d ON d.name_id = b.building_id WHERE b.planet_id = pid; IF rv IS NULL THEN rv := 0; END IF; RETURN rv; END; $$ LANGUAGE plpgsql; -- -- Creates a planet -- -- Parameters: -- sid Stellar system ID -- o Orbit number -- ipop Initial population -- npics Amount of planet pictures -- CREATE OR REPLACE FUNCTION verse.create_planet( sid INT , o INT , ipop REAL , npics INT ) RETURNS VOID STRICT VOLATILE SECURITY INVOKER AS $$ DECLARE pnid INT; bworkers INT; bpp INT; uid BIGINT; utp update_type; happiness REAL; BEGIN -- Planet name and planet pnid := naming.create_map_name( 'P' ); INSERT INTO verse.planets ( name_id , system_id , orbit , picture , population ) VALUES ( pnid , sid , o , 1 + floor( random() * npics ) , ipop ); -- Create build queues INSERT INTO verse.bld_queues( planet_id , money , work ) VALUES ( pnid , 0 , 0 ); INSERT INTO verse.mil_queues( planet_id , money , work ) VALUES ( pnid , 0 , 0 ); -- Insert initial buildings SELECT INTO bworkers SUM( d.workers ) FROM tech.buildings_view d INNER JOIN tech.basic_buildables b USING( name_id ); bpp := floor( 0.5 * ipop / bworkers ); INSERT INTO verse.planet_buildings ( planet_id , building_id , amount , damage ) SELECT pnid , d.name_id , bpp , 0.0 FROM tech.buildings_view d INNER JOIN tech.basic_buildables b USING( name_id ); -- Compute initial happiness happiness := verse.compute_happiness( ipop , bpp * bworkers , verse.get_raw_production( pnid , 'DEF'::building_output_type ) , 0 ); INSERT INTO verse.planet_happiness ( planet_id , current , target ) VALUES ( pnid , ipop * happiness , happiness ); -- Compute initial income and upkeep INSERT INTO verse.planet_money ( planet_id , income , upkeep ) VALUES ( pnid , verse.compute_income( ipop , happiness , verse.get_raw_production( pnid , 'CASH'::building_output_type ) ) , verse.get_planet_upkeep( pnid ) ); -- Add planet update records FOR utp IN SELECT x FROM unnest( enum_range( NULL::update_type ) ) AS x WHERE x::text LIKE 'PLANET_%' LOOP INSERT INTO sys.updates( gu_type ) VALUES ( utp ) RETURNING id INTO uid; INSERT INTO verse.updates ( update_id , planet_id ) VALUES ( uid , pnid ); END LOOP; END; $$ LANGUAGE plpgsql; -- -- Creates a stellar system -- -- Parameters: -- sx, sy Coordinates -- ipop Initial population of planets -- npics Amount of planet pictures -- CREATE OR REPLACE FUNCTION verse.create_system( sx INT , sy INT , ipop REAL , npics INT ) RETURNS VOID STRICT VOLATILE SECURITY INVOKER AS $$ DECLARE sid INT; orbit INT; BEGIN -- Create system INSERT INTO verse.systems ( x , y ) VALUES ( sx , sy ) RETURNING id INTO sid; -- Create planets FOR orbit IN 1 .. 5 LOOP PERFORM verse.create_planet( sid , orbit , ipop , npics ); END LOOP; END; $$ LANGUAGE plpgsql; -- -- Generate multiple systems at the specified coordinates -- -- Parameters: -- (x0,y0)-(x1,y1) Area to generate -- ipop Initial population -- CREATE OR REPLACE FUNCTION verse.create_systems( x0 INT , y0 INT , x1 INT , y1 INT , ipop REAL ) RETURNS VOID STRICT VOLATILE SECURITY INVOKER AS $$ DECLARE x INT; y INT; npics INT; BEGIN npics := floor( sys.get_constant( 'game.universe.pictures' ) ); FOR x IN x0 .. x1 LOOP FOR y IN y0 .. y1 LOOP PERFORM verse.create_system( x , y , ipop , npics ); END LOOP; END LOOP; END; $$ LANGUAGE plpgsql; -- -- Generate the initial universe -- CREATE OR REPLACE FUNCTION verse.generate_initial_universe( ) RETURNS VOID STRICT VOLATILE SECURITY INVOKER AS $$ DECLARE sz INT; pop REAL; npics INT; BEGIN sz := floor( sys.get_constant( 'game.universe.initialSize' ) ); pop := sys.get_constant( 'game.universe.initialPopulation' ); PERFORM verse.create_systems( -sz , -sz , sz , sz , pop ); END; $$ LANGUAGE plpgsql; -- -- Expand the universe -- CREATE OR REPLACE FUNCTION verse.expand_universe( ) RETURNS VOID STRICT VOLATILE SECURITY INVOKER AS $$ DECLARE min_x INT; max_x INT; min_y INT; max_y INT; x_size INT; y_size INT; x_axis BOOLEAN; posit BOOLEAN; x0 INT; y0 INT; x1 INT; y1 INT; pop REAL; BEGIN -- Get current bounds SELECT INTO min_x , max_x , min_y , max_y MIN(x) , MAX(x) , MIN(y) , MAX(y) FROM verse.systems; x_size := 1 + max_x - min_x; y_size := 1 + max_y - min_y; -- Find out which axis/direction to use x_axis := ( x_size = y_size ); IF x_axis THEN posit := ( max_x = -min_x ); ELSE posit := ( max_y = -min_y ); END IF; -- Compute area coordinates IF x_axis THEN x0 := ( CASE posit WHEN TRUE THEN max_x + 1 ELSE min_x - 1 END ); x1 := x0; y0 := min_y; y1 := max_y; ELSE y0 := ( CASE posit WHEN TRUE THEN max_y + 1 ELSE min_y - 1 END ); y1 := y0; x0 := min_x; x1 := max_x; END IF; -- Get average population and generate new systems SELECT INTO pop AVG( population ) FROM verse.planets; PERFORM verse.create_systems( x0 , y0 , x1 , y1 , pop ); END; $$ LANGUAGE plpgsql; -- -- Universe generator function -- -- Called by the game engine; generate the initial universe if it is empty, or expand it -- if the ratio of available planets is too low. -- CREATE OR REPLACE FUNCTION verse.generate( ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE p_count INT; f_ratio REAL; BEGIN -- Get total planet count SELECT INTO p_count 5 * count(*) FROM verse.systems; -- Empty universe -> initialise IF p_count = 0 THEN PERFORM verse.generate_initial_universe( ); RETURN; END IF; -- Get available planets ratio SELECT INTO f_ratio count(*)::REAL / p_count::REAL FROM verse.available_planets; -- Expand universe if required IF f_ratio < sys.get_constant( 'game.universe.minFreeRatio' ) THEN PERFORM verse.expand_universe( ); END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION verse.generate() TO :dbuser;