-- LegacyWorlds Beta 6 -- PostgreSQL database scripts -- -- Functions and views for technologies and buildables -- -- Copyright(C) 2004-2010, DeepClone Development -- -------------------------------------------------------- -- -- "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; -- -- Categories view -- CREATE VIEW tech.categories_view AS SELECT ns.name AS name , ds.name AS description FROM tech.categories c INNER JOIN defs.strings ns ON ns.id = c.name_id INNER JOIN defs.strings ds ON ds.id = c.description_id; GRANT SELECT ON tech.categories_view TO :dbuser; -- -- Technologies view -- CREATE VIEW tech.technologies_view AS SELECT cs.name AS category , ns.name AS name , ds.name AS description , t.points , t.cost FROM tech.technologies t INNER JOIN defs.strings cs ON cs.id = t.category_id INNER JOIN defs.strings ns ON ns.id = t.name_id INNER JOIN defs.strings ds ON ds.id = t.description_id; GRANT SELECT ON tech.technologies_view TO :dbuser; -- -- Dependencies view -- CREATE VIEW tech.dependencies_view AS SELECT ts.name AS technology , ds.name AS dependency FROM tech.dependencies d INNER JOIN defs.strings ts ON ts.id = d.technology_id INNER JOIN defs.strings ds ON ds.id = d.depends_on; GRANT SELECT ON tech.dependencies_view TO :dbuser; -- -- Creates or updates a technology category -- -- Parameters: -- cat_name String identifier of the category's name -- cat_desc String identifier of the category's description -- -- Returns: -- 0 No error -- 1 Name string not found -- 2 Description string not found -- CREATE OR REPLACE FUNCTION tech.uoc_category( cat_name TEXT , cat_desc TEXT ) RETURNS INT STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE cn_id INT; cd_id INT; BEGIN -- Get name / description identifiers SELECT INTO cn_id id FROM defs.strings WHERE name = cat_name; IF NOT FOUND THEN RETURN 1; END IF; SELECT INTO cd_id id FROM defs.strings WHERE name = cat_desc; IF NOT FOUND THEN RETURN 2; END IF; -- Create or update the category BEGIN INSERT INTO tech.categories ( name_id , description_id ) VALUES ( cn_id , cd_id ); EXCEPTION WHEN unique_violation THEN UPDATE tech.categories SET description_id = cd_id WHERE name_id = cn_id; END; RETURN 0; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION tech.uoc_category( TEXT , TEXT ) to :dbuser; -- -- Creates or updates a technology. If there are dependencies, clear them. -- -- Parameters: -- nt_name Name string identifier -- nt_category Category string identifier -- nt_desc Description string identifier -- nt_points Research points for the technology -- nt_cost Cost of the technology -- -- Returns: -- 0 No error -- 1 Name string not found -- 2 Category not found -- 3 Description string not found -- 4 Invalid parameters (points or cost) -- CREATE OR REPLACE FUNCTION tech.uoc_technology( nt_name TEXT , nt_category TEXT , nt_desc TEXT , nt_points INT , nt_cost INT ) RETURNS INT STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE n_id INT; c_id INT; d_id INT; BEGIN -- Get name, category and description identifiers SELECT INTO n_id id FROM defs.strings WHERE name = nt_name; IF NOT FOUND THEN RETURN 1; END IF; SELECT INTO c_id c.name_id FROM tech.categories c INNER JOIN defs.strings s ON s.id = c.name_id AND s.name = nt_category; IF NOT FOUND THEN RETURN 2; END IF; SELECT INTO d_id id FROM defs.strings WHERE name = nt_desc; IF NOT FOUND THEN RETURN 3; END IF; -- Create or update the technology BEGIN BEGIN INSERT INTO tech.technologies ( name_id , category_id , description_id , points , cost ) VALUES ( n_id , c_id , d_id , nt_points , nt_cost ); EXCEPTION WHEN unique_violation THEN UPDATE tech.technologies SET category_id = c_id , description_id = cd_id , points = nt_points , cost = nt_cost WHERE name_id = n_id; DELETE FROM tech.dependencies WHERE technology_id = n_id; END; EXCEPTION WHEN check_violation THEN RETURN 4; END; RETURN 0; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION tech.uoc_technology( TEXT , TEXT , TEXT , INT , INT ) to :dbuser; -- -- Adds a technology dependency -- -- Parameters: -- nd_name Name of the dependent technology -- nd_dep Name of the dependency -- -- Returns: -- 0 No error -- 1 Technology not found -- 2 Dependency not found -- 3 Duplicate dependency -- CREATE OR REPLACE FUNCTION tech.add_dependency( nd_name TEXT , nd_dep TEXT ) RETURNS INT STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE t_id INT; d_id INT; BEGIN -- Get technology SELECT INTO t_id t.name_id FROM tech.technologies t INNER JOIN defs.strings s ON s.id = t.name_id AND s.name = nd_name; IF NOT FOUND THEN RETURN 1; END IF; -- Get dependency SELECT INTO d_id t.name_id FROM tech.technologies t INNER JOIN defs.strings s ON s.id = t.name_id AND s.name = nd_dep; IF NOT FOUND THEN RETURN 2; END IF; -- Add dependency BEGIN INSERT INTO tech.dependencies ( technology_id , depends_on ) VALUES ( t_id , d_id ); EXCEPTION WHEN unique_violation THEN RETURN 3; END; RETURN 0; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION tech.add_dependency( TEXT, TEXT ) TO :dbuser; -- -- Creates or updates a buildable definition -- -- Parameters: -- bdn Buildable name -- bdd Buildable description -- bdc Cost -- bdw Work -- bdu Upkeep -- bdtn Dependency -- -- Returns: -- the buildable's identifier -- CREATE OR REPLACE FUNCTION tech.uoc_buildable( bdn TEXT , bdd TEXT , bdc INT , bdw INT , bdu INT , bdtn TEXT ) 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.name_id FROM tech.technologies tl INNER JOIN defs.strings s ON s.id = tl.name_id WHERE s.name = bdtn; 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 , technology_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 , '' ); 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 -- 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 ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE bdid INT; BEGIN bdid := tech.uoc_buildable( bdn , bdd , bdc , bdw , bdu , bdtn ); 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 ) 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 , '' ); 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 name -- CREATE OR REPLACE FUNCTION tech.uoc_ship( sn TEXT , sd TEXT , sc INT , sw INT , su INT , sp INT , sft INT , stdn TEXT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE bdid INT; BEGIN bdid := tech.uoc_buildable( sn , sd , sc , sw , su , stdn ); 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 ) TO :dbuser;