379 lines
8.5 KiB
PL/PgSQL
379 lines
8.5 KiB
PL/PgSQL
-- 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;
|
|
|
|
|
|
|
|
--
|
|
-- 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;
|
|
|
|
|