This repository has been archived on 2024-07-18. You can view files and clone it, but cannot push or open issues or pull requests.
lwb6/legacyworlds-server/legacyworlds-server-data/db-structure/parts/updates/020-empire-research.sql

166 lines
5.1 KiB
PL/PgSQL

-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Game updates - empire research
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
--
-- Prepare the research update
--
-- Parameters:
-- update_id The current update's identifier
--
-- Returns:
-- a set of tech._research_update_input records
--
CREATE OR REPLACE FUNCTION emp.prepare_research_update( update_id BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
-- Lock empires for update and planets for share
PERFORM e.name_id FROM sys.updates su
INNER JOIN emp.updates eu ON eu.update_id = su.id
INNER JOIN emp.empires e ON eu.empire_id = e.name_id
INNER JOIN emp.planets ep ON ep.empire_id = e.name_id
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
WHERE su.last_tick = update_id AND su.status = 'PROCESSING'
AND su.gu_type = 'EMPIRE_RESEARCH'
FOR UPDATE OF e
FOR SHARE OF ep , p;
-- Create temporary table for update output and grant INSERT privilege
-- to session user.
CREATE TEMPORARY TABLE research_update_output(
empire_id INT ,
technology TEXT ,
creation BOOLEAN ,
points DOUBLE PRECISION ,
priority INT
);
IF session_user <> current_user THEN
EXECUTE 'GRANT INSERT ON research_update_output TO ' || session_user;
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION emp.prepare_research_update( update_id BIGINT ) TO :dbuser;
--
-- Research update input views
--
CREATE VIEW emp.rui_inprogress_view
AS SELECT su.last_tick AS update_id , er.empire_id , ns.name AS technology ,
er.accumulated AS points , er.priority AS priority
FROM sys.updates su
INNER JOIN emp.updates eu ON eu.update_id = su.id
INNER JOIN emp.research er ON er.empire_id = eu.empire_id
INNER JOIN defs.strings ns ON ns.id = er.technology_id
WHERE su.status = 'PROCESSING'
AND su.gu_type = 'EMPIRE_RESEARCH';
CREATE VIEW emp.rui_researched_view
AS SELECT su.last_tick AS update_id , er.empire_id , ns.name AS technology ,
er.implemented AS implemented
FROM sys.updates su
INNER JOIN emp.updates eu ON eu.update_id = su.id
INNER JOIN emp.researched_technologies er
ON er.empire_id = eu.empire_id
INNER JOIN defs.strings ns ON ns.id = er.technology_id
WHERE su.status = 'PROCESSING'
AND su.gu_type = 'EMPIRE_RESEARCH';
CREATE VIEW emp.research_update_input_view
AS SELECT update_id , empire_id , technology ,
NULL::BOOLEAN AS implemented , points , priority
FROM emp.rui_inprogress_view
UNION ALL SELECT update_id , empire_id , technology ,
implemented , NULL::DOUBLE PRECISION AS points ,
NULL::INT AS priority
FROM emp.rui_researched_view;
GRANT SELECT ON emp.research_update_input_view TO :dbuser;
--
-- Research points production view
--
CREATE VIEW emp.research_points_production
AS SELECT su.last_tick AS update_id , e.name_id AS empire_id ,
( sum( p.population ) * sys.get_constant( 'game.research.perPopUnit' )
/ ( sys.get_constant( 'game.updatesPerDay' ) * ( CASE
WHEN v.status = 'PROCESSED' THEN
sys.get_constant( 'game.research.perPopUnit' )
ELSE
1.0
END ) ) ) AS points
FROM sys.updates su
INNER JOIN emp.updates eu ON eu.update_id = su.id
INNER JOIN emp.empires e ON eu.empire_id = e.name_id
INNER JOIN emp.planets ep ON ep.empire_id = e.name_id
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
INNER JOIN naming.empire_names en ON en.id = e.name_id
LEFT OUTER JOIN users.vacations v ON v.account_id = en.owner_id
WHERE su.status = 'PROCESSING' AND su.gu_type = 'EMPIRE_RESEARCH'
GROUP BY su.last_tick , e.name_id , v.status;
GRANT SELECT ON emp.research_points_production TO :dbuser;
--
-- Submit the contents of the research update table
--
CREATE OR REPLACE FUNCTION emp.submit_research_update( )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
-- Delete finished research topics
DELETE FROM emp.research er
USING research_update_output ruo , defs.strings ns
WHERE er.empire_id = ruo.empire_id
AND er.technology_id = ns.id AND ns.name = ruo.technology
AND ruo.points IS NULL;
-- Insert researched technologies
INSERT INTO emp.researched_technologies ( empire_id , technology_id , implemented )
SELECT ruo.empire_id , ns.id , FALSE
FROM research_update_output ruo
INNER JOIN defs.strings ns ON ns.name = ruo.technology
WHERE ruo.points IS NULL;
-- Insert new research topics
INSERT INTO emp.research ( empire_id , technology_id , accumulated , priority )
SELECT ruo.empire_id , ns.id , ruo.points , ruo.priority
FROM research_update_output ruo
INNER JOIN defs.strings ns ON ns.name = ruo.technology
WHERE ruo.points IS NOT NULL AND ruo.creation;
-- Update existing research topics
UPDATE emp.research er
SET accumulated = ruo.points , priority = ruo.priority
FROM research_update_output ruo , defs.strings ns
WHERE ruo.points IS NOT NULL AND NOT ruo.creation
AND ns.name = ruo.technology
AND er.technology_id = ns.id
AND er.empire_id = ruo.empire_id;
-- Drop temporary table
DROP TABLE research_update_output;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION emp.submit_research_update( ) TO :dbuser;