228 lines
5.7 KiB
MySQL
228 lines
5.7 KiB
MySQL
|
-- LegacyWorlds Beta 6
|
||
|
-- PostgreSQL database scripts
|
||
|
--
|
||
|
-- Research mananagement functions and views
|
||
|
--
|
||
|
-- Copyright(C) 2004-2011, DeepClone Development
|
||
|
-- --------------------------------------------------------
|
||
|
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Implement a technology
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- e_id Empire identifier
|
||
|
-- t_name Technology name
|
||
|
--
|
||
|
-- Returns:
|
||
|
-- 0 on success
|
||
|
-- 1 if the empire does not posses the necessary resources
|
||
|
-- 2 if the technology or empire were not found
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION emp.implement_tech( e_id INT , t_name TEXT )
|
||
|
RETURNS INT
|
||
|
STRICT VOLATILE
|
||
|
SECURITY DEFINER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
e_cash DOUBLE PRECISION;
|
||
|
t_id INT;
|
||
|
t_cost DOUBLE PRECISION;
|
||
|
BEGIN
|
||
|
SELECT INTO e_cash , t_id , t_cost e.cash , ns.id , td.cost
|
||
|
FROM defs.strings ns
|
||
|
INNER JOIN tech.technologies td
|
||
|
ON td.name_id = ns.id
|
||
|
INNER JOIN emp.researched_technologies rt
|
||
|
ON rt.technology_id = td.name_id
|
||
|
INNER JOIN emp.empires e
|
||
|
ON rt.empire_id = e.name_id
|
||
|
WHERE e.name_id = e_id AND ns.name = t_name
|
||
|
FOR UPDATE OF e , rt;
|
||
|
IF NOT FOUND THEN
|
||
|
RETURN 2;
|
||
|
END IF;
|
||
|
|
||
|
IF e_cash < t_cost THEN
|
||
|
RETURN 1;
|
||
|
END IF;
|
||
|
|
||
|
UPDATE emp.empires
|
||
|
SET cash = e_cash - t_cost
|
||
|
WHERE name_id = e_id;
|
||
|
UPDATE emp.researched_technologies
|
||
|
SET implemented = TRUE
|
||
|
WHERE empire_id = e_id AND technology_id = t_id;
|
||
|
|
||
|
RETURN 0;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
GRANT EXECUTE ON FUNCTION emp.implement_tech( INT , TEXT ) TO :dbuser;
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Prepare for research priorities updates
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION emp.prepare_research_priorities_update( )
|
||
|
RETURNS VOID
|
||
|
STRICT VOLATILE
|
||
|
SECURITY DEFINER
|
||
|
AS $$
|
||
|
BEGIN
|
||
|
CREATE TEMPORARY TABLE research_priorities_updates(
|
||
|
technology TEXT ,
|
||
|
priority INT
|
||
|
);
|
||
|
CREATE INDEX rpu_technology ON research_priorities_updates ( technology );
|
||
|
IF session_user <> current_user THEN
|
||
|
EXECUTE 'GRANT INSERT ON research_priorities_updates TO ' || session_user;
|
||
|
END IF;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
GRANT EXECUTE ON FUNCTION emp.prepare_research_priorities_update( ) TO :dbuser;
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Applies research priorities updates
|
||
|
--
|
||
|
-- Parameters:
|
||
|
-- e_id identifier of the empire the updates should be applied to
|
||
|
--
|
||
|
-- Returns:
|
||
|
-- an error code:
|
||
|
-- 0 success
|
||
|
-- 1 list of updates does not match current research topics
|
||
|
-- 2 invalid priorities
|
||
|
--
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION emp.apply_research_priorities( IN e_id INT )
|
||
|
RETURNS INT
|
||
|
STRICT VOLATILE
|
||
|
SECURITY DEFINER
|
||
|
AS $$
|
||
|
DECLARE
|
||
|
rec RECORD;
|
||
|
t INT;
|
||
|
rval INT;
|
||
|
BEGIN
|
||
|
-- Lock empire and research info
|
||
|
PERFORM er.technology_id
|
||
|
FROM emp.empires e
|
||
|
INNER JOIN emp.research er ON er.empire_id = e.name_id
|
||
|
WHERE e.name_id = e_id
|
||
|
FOR UPDATE OF e , er;
|
||
|
|
||
|
-- Check values
|
||
|
t := 0;
|
||
|
rval := 0;
|
||
|
FOR rec IN SELECT rpu.priority , r.technology_id FROM research_priorities_updates rpu
|
||
|
LEFT OUTER JOIN emp.research_view r
|
||
|
ON ( r.detailed AND r.technology = rpu.technology )
|
||
|
OR ( NOT r.detailed AND ( 'unknown-' || ( r.technology_id * e_id )::TEXT ) = rpu.technology )
|
||
|
WHERE r.empire = e_id OR r.empire IS NULL
|
||
|
UNION SELECT rpu.priority , r.technology_id FROM research_priorities_updates rpu
|
||
|
RIGHT OUTER JOIN emp.research_view r
|
||
|
ON ( r.detailed AND r.technology = rpu.technology )
|
||
|
OR ( NOT r.detailed AND ( 'unknown-' || ( r.technology_id * e_id )::TEXT ) = rpu.technology )
|
||
|
WHERE r.empire = e_id
|
||
|
LOOP
|
||
|
IF rec.priority IS NULL OR rec.technology_id IS NULL THEN
|
||
|
rval := 1;
|
||
|
EXIT;
|
||
|
ELSIF rec.priority NOT BETWEEN 0 AND 100 THEN
|
||
|
rval := 2;
|
||
|
EXIT;
|
||
|
END IF;
|
||
|
t := t + rec.priority;
|
||
|
END LOOP;
|
||
|
IF rval = 0 AND t <> 100 THEN
|
||
|
rval := 2;
|
||
|
END IF;
|
||
|
|
||
|
-- Update research info
|
||
|
IF rval = 0 THEN
|
||
|
UPDATE emp.research er SET priority = rpu.priority
|
||
|
FROM research_priorities_updates rpu , emp.research_view rv
|
||
|
WHERE ( rpu.technology = CASE
|
||
|
WHEN rv.detailed THEN
|
||
|
rv.technology
|
||
|
ELSE
|
||
|
( 'unknown-' || ( rv.technology_id * e_id )::TEXT )
|
||
|
END )
|
||
|
AND rv.empire = e_id
|
||
|
AND er.empire_id = e_id
|
||
|
AND er.technology_id = rv.technology_id;
|
||
|
END IF;
|
||
|
DROP TABLE research_priorities_updates;
|
||
|
RETURN rval;
|
||
|
END;
|
||
|
$$ LANGUAGE plpgsql;
|
||
|
|
||
|
GRANT EXECUTE ON FUNCTION emp.apply_research_priorities( INT ) TO :dbuser;
|
||
|
|
||
|
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Base research view
|
||
|
--
|
||
|
|
||
|
CREATE VIEW emp.base_research_view
|
||
|
AS SELECT er.empire_id AS empire , er.technology_id , ns.name AS technology ,
|
||
|
td.points AS required , ( CASE
|
||
|
WHEN er.accumulated > td.points THEN
|
||
|
td.points - 1
|
||
|
ELSE
|
||
|
er.accumulated
|
||
|
END ) AS accumulated , er.priority
|
||
|
FROM emp.research er
|
||
|
INNER JOIN tech.technologies td ON td.name_id = er.technology_id
|
||
|
INNER JOIN defs.strings ns ON ns.id = er.technology_id;
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Research view
|
||
|
--
|
||
|
|
||
|
CREATE VIEW emp.research_view
|
||
|
AS SELECT empire , technology , technology_id ,
|
||
|
FLOOR( 100 * accumulated / required )::INT AS completion ,
|
||
|
( accumulated >= sys.get_constant( 'game.research.minPoints' )
|
||
|
OR accumulated / required >= sys.get_constant( 'game.research.minRatio' ) ) AS detailed ,
|
||
|
priority
|
||
|
FROM emp.base_research_view;
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Researched and implemented technologies view
|
||
|
|
||
|
CREATE VIEW emp.known_techs_view
|
||
|
AS SELECT et.empire_id AS empire , et.technology_id , ns.name AS technology ,
|
||
|
( CASE WHEN et.implemented THEN NULL::INT ELSE td.cost END ) AS cost
|
||
|
FROM emp.researched_technologies et
|
||
|
INNER JOIN tech.technologies td ON td.name_id = et.technology_id
|
||
|
INNER JOIN defs.strings ns ON ns.id = et.technology_id;
|
||
|
|
||
|
|
||
|
--
|
||
|
-- Combined research and technologies view
|
||
|
--
|
||
|
|
||
|
CREATE VIEW emp.technologies_view
|
||
|
AS SELECT empire , technology_id , technology ,
|
||
|
detailed , completion , priority , NULL::INT AS cost
|
||
|
FROM emp.research_view
|
||
|
UNION ALL SELECT empire , technology_id , technology ,
|
||
|
TRUE AS detailed , NULL::INT AS completion , NULL::INT AS priority , cost
|
||
|
FROM emp.known_techs_view;
|
||
|
|
||
|
GRANT SELECT ON emp.technologies_view TO :dbuser;
|
||
|
|