-- LegacyWorlds Beta 6 -- PostgreSQL database scripts -- -- Functions and views for technologies and buildables -- -- Copyright(C) 2004-2010, DeepClone Development -- -------------------------------------------------------- /* * Return type for technology management functions * ------------------------------------------------ * * This enumerated type is used for the return values of all technology * management functions. This includes defs.uoc_technology() of course, * but also defs.techdep_add() and defs.techdep_remove(). */ DROP TYPE IF EXISTS defs.technology_update_result CASCADE; CREATE TYPE defs.technology_update_result AS ENUM( /* The technology definition or dependency was created */ 'CREATED' , /* The technology definition was updated */ 'UPDATED' , /* The dependency was deleted */ 'DELETED' , /* The specified dependency does not exist */ 'MISSING' , /* One (or more) of the numeric parameters is invalid */ 'BAD_VALUE' , /* The name, description, discovery or category string identifiers * were not valid string identifiers. */ 'BAD_STRINGS' , /* The specified description and/or discovery string was in use by * another technology. */ 'DUP_STRING' , /* The dependency would cause a cycle */ 'CYCLE' , /* The dependency would be redundant */ 'REDUNDANT' ); /* * Update or create a technology definition * ----------------------------------------- * * This stored procedure can be used to update existing technology definitions * or create new records. It will not affect technology dependencies: no * depedencies will be added when creating a new technology, and existing * dependencies will be conserved when updating. * * If a technology already exists, check for empires researching that * technology, and scale their current progress accordingly. * * Parameters: * _name Text identifier of the name string * _category Text identifier of the category string * _discovery Text identifier of the discovery string * _description Text identifier of the description string * _price Monetary cost to implement the technology * _points Amount of points required to research teh technology * * Returns: * ? One of the following return codes: CREATED, UPDATED, * BAD_VALUE, BAD_STRINGS, DUP_STRING */ DROP FUNCTION IF EXISTS defs.uoc_technology( TEXT , TEXT , TEXT , TEXT , BIGINT , BIGINT ) CASCADE; CREATE FUNCTION defs.uoc_technology( _name TEXT , _category TEXT , _discovery TEXT , _description TEXT , _price BIGINT , _points BIGINT ) RETURNS defs.technology_update_result LANGUAGE PLPGSQL STRICT VOLATILE SECURITY DEFINER AS $uoc_technology$ DECLARE _name_id INT; _disc_id INT; _desc_id INT; _cat_id INT; _old_points BIGINT; _multi DOUBLE PRECISION; BEGIN -- Get all string identifiers SELECT INTO _name_id id FROM defs.strings WHERE name = _name; IF NOT FOUND THEN RETURN 'BAD_STRINGS'; END IF; SELECT INTO _desc_id id FROM defs.strings WHERE name = _description; IF NOT FOUND THEN RETURN 'BAD_STRINGS'; END IF; SELECT INTO _disc_id id FROM defs.strings WHERE name = _discovery; IF NOT FOUND THEN RETURN 'BAD_STRINGS'; END IF; SELECT INTO _cat_id id FROM defs.strings WHERE name = _category; IF NOT FOUND THEN RETURN 'BAD_STRINGS'; END IF; -- Try inserting the record BEGIN INSERT INTO defs.technologies ( technology_name_id , technology_category_id , technology_discovery_id , technology_description_id , technology_price , technology_points ) VALUES ( _name_id , _cat_id , _disc_id , _desc_id , _price , _points ); RETURN 'CREATED'; EXCEPTION WHEN unique_violation THEN -- Continue, we can't determine which error this -- was about at this point. END; -- Lock existing definition and empire research records PERFORM 1 FROM defs.technologies _def LEFT OUTER JOIN ( SELECT technology_name_id FROM emp.technologies_v2 _tech WHERE technology_name_id = _name_id AND emptech_state = 'RESEARCH' FOR UPDATE OF _tech ) _emps USING ( technology_name_id ) WHERE technology_name_id = _name_id FOR UPDATE OF _def; IF NOT FOUND THEN RETURN 'DUP_STRING'; END IF; -- Get old value for research points SELECT INTO _old_points technology_points FROM defs.technologies WHERE technology_name_id = _name_id; -- Update the record BEGIN UPDATE defs.technologies SET technology_category_id = _cat_id , technology_discovery_id = _disc_id , technology_description_id = _desc_id , technology_price = _price , technology_points = _points WHERE technology_name_id = _name_id; EXCEPTION WHEN unique_violation THEN RETURN 'DUP_STRING'; END; -- Update empire research if necessary IF _old_points <> _points THEN _multi := _points::DOUBLE PRECISION / _old_points::DOUBLE PRECISION; UPDATE emp.technologies_v2 SET emptech_points = emptech_points * _multi WHERE technology_name_id = _name_id AND emptech_points IS NOT NULL; END IF; RETURN 'UPDATED'; EXCEPTION WHEN check_violation THEN RETURN 'BAD_VALUE'; END; $uoc_technology$; REVOKE EXECUTE ON FUNCTION defs.uoc_technology( TEXT , TEXT , TEXT , TEXT , BIGINT , BIGINT ) FROM PUBLIC; GRANT EXECUTE ON FUNCTION defs.uoc_technology( TEXT , TEXT , TEXT , TEXT , BIGINT , BIGINT ) TO :dbuser; /* * Add a technology dependency * ---------------------------- * * This stored procedure attempts to create a dependency between two * technologies by looking them up by name then inserting the pair in the * dependency table. * * Parameters: * _dependent The name of the dependent technology * _dependency The name of the dependency * * Returns: * ? One of the following return codes: CREATED, * BAD_STRINGS, CYCLE, REDUNDANT */ DROP FUNCTION IF EXISTS defs.techdep_add( TEXT , TEXT ); CREATE FUNCTION defs.techdep_add( _dependent TEXT , _dependency TEXT ) RETURNS defs.technology_update_result LANGUAGE PLPGSQL STRICT VOLATILE SECURITY DEFINER AS $techdep_add$ DECLARE _tech1_id INT; _tech2_id INT; BEGIN SELECT INTO _tech1_id , _tech2_id _str1.id , _str2.id FROM defs.strings _str1 CROSS JOIN defs.strings _str2 WHERE _str1.name = _dependent AND _str2.name = _dependency; IF NOT FOUND THEN RETURN 'BAD_STRINGS'; END IF; INSERT INTO defs.technology_dependencies ( technology_name_id , technology_name_id_depends ) VALUES ( _tech1_id , _tech2_id ); RETURN 'CREATED'; EXCEPTION WHEN foreign_key_violation THEN RETURN 'BAD_STRINGS'; WHEN unique_violation THEN RETURN 'REDUNDANT'; WHEN check_violation THEN IF SQLERRM LIKE '%Cycle detected%' THEN RETURN 'CYCLE'; END IF; RETURN 'REDUNDANT'; END; $techdep_add$; REVOKE EXECUTE ON FUNCTION defs.techdep_add( TEXT , TEXT ) FROM PUBLIC; GRANT EXECUTE ON FUNCTION defs.techdep_add( TEXT , TEXT ) TO :dbuser; /* * Remove a technology dependency * ------------------------------- * * This stored procedure removes a dependency from a technology to another. * * Parameters: * _dependent The name of the dependent technology * _dependency The name of the dependency * * Returns: * ? One of the following return codes: DELETED, MISSING */ DROP FUNCTION IF EXISTS defs.techdep_remove( TEXT , TEXT ); CREATE FUNCTION defs.techdep_remove( _dependent TEXT , _dependency TEXT ) RETURNS defs.technology_update_result LANGUAGE PLPGSQL STRICT VOLATILE SECURITY DEFINER AS $techdep_remove$ DECLARE _dep_id INT; BEGIN SELECT INTO _dep_id techdep_id FROM defs.technology_dependencies _td INNER JOIN defs.strings _str1 ON _str1.id = _td.technology_name_id INNER JOIN defs.strings _str2 ON _str2.id = _td.technology_name_id_depends WHERE _str1.name = _dependent AND _str2.name = _dependency FOR UPDATE OF _td; IF NOT FOUND THEN RETURN 'MISSING'; END IF; DELETE FROM defs.technology_dependencies WHERE techdep_id = _dep_id; RETURN 'DELETED'; END; $techdep_remove$; REVOKE EXECUTE ON FUNCTION defs.techdep_remove( TEXT , TEXT ) FROM PUBLIC; GRANT EXECUTE ON FUNCTION defs.techdep_remove( TEXT , TEXT ) TO :dbuser; -- ******************************************************** -- OLD CODE BELOW -- ******************************************************** -- -- "Basic" buildables view (buildables that do not depend on any technology) -- CREATE VIEW tech.basic_buildables AS SELECT b.* FROM tech.buildables b LEFT OUTER JOIN tech.buildable_requirements r ON r.buildable_id = b.name_id WHERE r.buildable_id IS NULL; -- -- Buildings view -- CREATE VIEW tech.buildings_view AS SELECT b.name_id , b.description_id , b.cost , b.work , b.upkeep , bld.workers , bld.output_type , bld.output FROM tech.buildables b INNER JOIN tech.buildings bld ON b.name_id = bld.buildable_id; -- -- Ships view -- CREATE VIEW tech.ships_view AS SELECT b.name_id , b.description_id , b.cost , b.work , b.upkeep , s.flight_time , s.power FROM tech.buildables b INNER JOIN tech.ships s ON b.name_id = s.buildable_id; -- -- Creates or updates a technology line -- -- Parameters: -- tln Tech line name -- tld Tech line description -- CREATE OR REPLACE FUNCTION tech.uoc_line( tln TEXT , tld TEXT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE nid INT; did INT; BEGIN -- Get string identifiers SELECT INTO nid id FROM defs.strings WHERE name = tln; SELECT INTO did id FROM defs.strings WHERE name = tld; -- Try creating / updating BEGIN INSERT INTO tech.lines ( name_id , description_id ) VALUES ( nid , did ); EXCEPTION WHEN unique_violation THEN UPDATE tech.lines SET description_id = did WHERE name_id = nid; END; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION tech.uoc_line( TEXT , TEXT ) TO :dbuser; -- -- Creates or updates a technology level -- -- Parameters: -- tln Tech line name -- lv Level -- lvn Level name -- lvd Level description -- lvp Points -- lvc Cost -- CREATE OR REPLACE FUNCTION tech.uoc_level( tln TEXT , lv INT , lvn TEXT , lvd TEXT , lvp INT , lvc INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE lid INT; nid INT; did INT; BEGIN -- Get tech line SELECT INTO lid t.name_id FROM tech.lines t INNER JOIN defs.strings s ON s.id = t.name_id WHERE s.name = tln; -- Get name / description IDs SELECT INTO nid id FROM defs.strings WHERE name = lvn; SELECT INTO did id FROM defs.strings WHERE name = lvd; -- Create or update the level BEGIN INSERT INTO tech.levels ( line_id , level , name_id , description_id , points , cost ) VALUES ( lid , lv , nid , did , lvp , lvc ); EXCEPTION WHEN unique_violation THEN UPDATE tech.levels SET name_id = nid , description_id = did , points = lvp , cost = lvc WHERE line_id = lid AND level = lv; END; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION tech.uoc_level( TEXT , INT , TEXT , TEXT , INT , INT ) to :dbuser; -- -- Creates or updates a buildable definition -- -- Parameters: -- bdn Buildable name -- bdd Buildable description -- bdc Cost -- bdw Work -- bdu Upkeep -- bdtn Dependency (name) -- bdtl Dependency (level) -- -- Returns: -- the buildable's identifier -- CREATE OR REPLACE FUNCTION tech.uoc_buildable( bdn TEXT , bdd TEXT , bdc INT , bdw INT , bdu INT , bdtn TEXT , bdtl INT ) RETURNS INT STRICT VOLATILE SECURITY INVOKER AS $$ DECLARE nid INT; did INT; tdid INT; BEGIN -- Get the various translations SELECT INTO nid id FROM defs.strings WHERE name = bdn; SELECT INTO did id FROM defs.strings WHERE name = bdd; IF bdtn <> '' THEN SELECT INTO tdid tl.id FROM tech.levels tl INNER JOIN defs.strings s ON s.id = tl.line_id WHERE s.name = bdtn AND tl.level = bdtl; END IF; -- Create or update the definition BEGIN INSERT INTO tech.buildables ( name_id , description_id , cost , work , upkeep ) VALUES ( nid , did , bdc , bdw , bdu ); EXCEPTION WHEN unique_violation THEN UPDATE tech.buildables SET description_id = did , cost = bdc , work = bdw , upkeep = bdu WHERE name_id = nid; END; -- Set dependencies DELETE FROM tech.buildable_requirements WHERE buildable_id = nid; IF bdtn <> '' THEN INSERT INTO tech.buildable_requirements ( buildable_id , level_id ) VALUES ( nid , tdid ); END IF; RETURN nid; END; $$ LANGUAGE plpgsql; -- -- Update or create a building definition (no tech dependency) -- -- Parameters: -- bdn Buildable name -- bdd Buildable description -- bdc Cost -- bdw Work -- bdu Upkeep -- bdwk Workers -- bdot Output type -- bdo Output -- CREATE OR REPLACE FUNCTION tech.uoc_building( bdn TEXT , bdd TEXT , bdc INT , bdw INT , bdu INT , bdwk INT , bdot building_output_type , bdo INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE bdid INT; BEGIN bdid := tech.uoc_buildable( bdn , bdd , bdc , bdw , bdu , '' , 0 ); PERFORM buildable_id FROM tech.ships WHERE buildable_id = bdid; IF FOUND THEN RAISE EXCEPTION 'Trying to transform a ship into a building'; END IF; BEGIN INSERT INTO tech.buildings (buildable_id, workers, output_type, output) VALUES (bdid , bdwk , bdot , bdo); EXCEPTION WHEN unique_violation THEN UPDATE tech.buildings SET workers = bdwk , output_type = bdot , output = bdo WHERE buildable_id = bdid; END; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION tech.uoc_building( TEXT , TEXT , INT , INT , INT , INT , building_output_type , INT ) TO :dbuser; -- -- Update or create a building definition (with tech dependency) -- -- Parameters: -- bdn Buildable name -- bdd Buildable description -- bdc Cost -- bdw Work -- bdu Upkeep -- bdwk Workers -- bdot Output type -- bdo Output -- bdtn Dependency (name) -- bdtl Dependency (level) -- CREATE OR REPLACE FUNCTION tech.uoc_building( bdn TEXT , bdd TEXT , bdc INT , bdw INT , bdu INT , bdwk INT , bdot building_output_type , bdo INT , bdtn TEXT , bdtl INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE bdid INT; BEGIN bdid := tech.uoc_buildable( bdn , bdd , bdc , bdw , bdu , bdtn , bdtl ); PERFORM buildable_id FROM tech.ships WHERE buildable_id = bdid; IF FOUND THEN RAISE EXCEPTION 'Trying to transform a ship into a building'; END IF; BEGIN INSERT INTO tech.buildings (buildable_id, workers, output_type, output) VALUES (bdid , bdwk , bdot , bdo); EXCEPTION WHEN unique_violation THEN UPDATE tech.buildings SET workers = bdwk , output_type = bdot , output = bdo WHERE buildable_id = bdid; END; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION tech.uoc_building( TEXT , TEXT , INT , INT , INT , INT , building_output_type , INT , TEXT , INT ) TO :dbuser; -- -- Update or create a ship definition (no tech dependency) -- -- Parameters: -- sn Buildable name -- sd Buildable description -- sc Cost -- sw Work -- su Upkeep -- sp Power -- sft Orbital flight time -- CREATE OR REPLACE FUNCTION tech.uoc_ship( sn TEXT , sd TEXT , sc INT , sw INT , su INT , sp INT , sft INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE bdid INT; BEGIN bdid := tech.uoc_buildable( sn , sd , sc , sw , su , '' , 0 ); PERFORM buildable_id FROM tech.buildings WHERE buildable_id = bdid; IF FOUND THEN RAISE EXCEPTION 'Trying to transform a building into a ship'; END IF; BEGIN INSERT INTO tech.ships (buildable_id, flight_time, power) VALUES (bdid , sft , sp); EXCEPTION WHEN unique_violation THEN UPDATE tech.ships SET flight_time = sft , power = sp WHERE buildable_id = bdid; END; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION tech.uoc_ship( TEXT , TEXT , INT , INT , INT , INT , INT ) TO :dbuser; -- -- Update or create a ship definition -- -- Parameters: -- sn Buildable name -- sd Buildable description -- sc Cost -- sw Work -- su Upkeep -- sp Power -- sft Orbital flight time -- stdn Tech line name -- stdl Tech level -- CREATE OR REPLACE FUNCTION tech.uoc_ship( sn TEXT , sd TEXT , sc INT , sw INT , su INT , sp INT , sft INT , stdn TEXT , stdl INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE bdid INT; BEGIN bdid := tech.uoc_buildable( sn , sd , sc , sw , su , stdn , stdl ); PERFORM buildable_id FROM tech.buildings WHERE buildable_id = bdid; IF FOUND THEN RAISE EXCEPTION 'Trying to transform a building into a ship'; END IF; BEGIN INSERT INTO tech.ships (buildable_id, flight_time, power) VALUES (bdid , sft , sp); EXCEPTION WHEN unique_violation THEN UPDATE tech.ships SET flight_time = sft , power = sp WHERE buildable_id = bdid; END; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION tech.uoc_ship( TEXT , TEXT , INT , INT , INT , INT , INT , TEXT , INT ) TO :dbuser;