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/functions/170-event-functions.sql

928 lines
26 KiB
PL/PgSQL

-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Functions and views to create and manipulate events
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- EVENT CREATION FUNCTIONS --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Creates a battle start event
--
-- Parameters:
-- b_id Battle identifier
--
CREATE OR REPLACE FUNCTION events.battle_start_event( b_id BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
l_id INT;
l_name TEXT;
pe_id INT;
c_tick BIGINT;
evt_id BIGINT;
BEGIN
-- Get location name and identifier
SELECT INTO l_id , l_name b.location_id , n.name
FROM battles.battles b
INNER JOIN naming.map_names n ON n.id = b.location_id
WHERE b.id = b_id;
-- Create message for all protagonists
c_tick := sys.get_tick( ) - 1;
FOR pe_id IN SELECT be.empire_id
FROM battles.battles b
INNER JOIN battles.protagonists bp ON bp.battle_id = b.id
INNER JOIN battles.empires be ON be.id = bp.empire_id
WHERE b.id = b_id
LOOP
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( pe_id , c_tick , 'PLANET' , 0 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.planet_events ( event_id , location_id , location_name , battle_id)
VALUES ( evt_id , l_id , l_name , b_id );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Creates a battle end event
--
-- Parameters:
-- b_id Battle identifier
--
CREATE OR REPLACE FUNCTION events.battle_end_event( b_id BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
l_id INT;
l_name TEXT;
pe_id INT;
c_tick BIGINT;
evt_id BIGINT;
BEGIN
-- Get location name and identifier
SELECT INTO l_id , l_name b.location_id , n.name
FROM battles.battles b
INNER JOIN naming.map_names n ON n.id = b.location_id
WHERE b.id = b_id;
-- Create message for all protagonists
c_tick := sys.get_tick( ) - 1;
FOR pe_id IN SELECT empire FROM battles.battles_list
WHERE battle = b_id AND last_update = last_tick
LOOP
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( pe_id , c_tick , 'PLANET' , 1 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.planet_events ( event_id , location_id , location_name , battle_id)
VALUES ( evt_id , l_id , l_name , b_id );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Creates a strike start / end event
--
-- Parameters:
-- p_id Planet identifier
-- sevt Whether to create a strike start or a strike end event
--
CREATE OR REPLACE FUNCTION events.strike_event( p_id INT , sevt BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
p_name TEXT;
po_id INT;
c_tick BIGINT;
evt_id BIGINT;
BEGIN
-- Get location name and owner identifier
SELECT INTO p_name , po_id n.name , ep.empire_id
FROM naming.map_names n
INNER JOIN emp.planets ep ON ep.planet_id = n.id
WHERE n.id = p_id;
IF NOT FOUND
THEN
RETURN;
END IF;
-- Create message
c_tick := sys.get_tick( ) - 1;
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( po_id , c_tick , 'PLANET' , ( CASE WHEN sevt THEN 2 ELSE 3 END ) , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.planet_events ( event_id , location_id , location_name )
VALUES ( evt_id , p_id , p_name );
END;
$$ LANGUAGE plpgsql;
--
-- Creates events for a planet's ownership change
--
-- Parameters:
-- p_id Planet identifier
-- no_id New owner's identifier
--
CREATE OR REPLACE FUNCTION events.planet_ochange_events( p_id INT , no_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
p_name VARCHAR(20);
no_name VARCHAR(20);
oo_id INT;
oo_name VARCHAR(20);
evt_id BIGINT;
c_tick BIGINT;
BEGIN
c_tick := sys.get_tick( ) - 1;
-- Get new owner's name and the planet's name
SELECT INTO p_name name FROM naming.map_names WHERE id = p_id;
SELECT INTO no_name name FROM naming.empire_names WHERE id = no_id;
-- Get previous owner's name and identifier
SELECT INTO oo_id , oo_name ep.empire_id , n.name
FROM emp.planets ep
INNER JOIN naming.empire_names n ON n.id = ep.empire_id
WHERE ep.planet_id = p_id;
-- If there is a previous owner, add planet loss event
IF FOUND
THEN
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( oo_id , c_tick , 'PLANET' , 4 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.planet_events ( event_id , location_id , location_name , empire_id , empire_name )
VALUES ( evt_id , p_id , p_name , no_id , no_name );
END IF;
-- Add planet taking event
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( no_id , c_tick , 'PLANET' , 6 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.planet_events ( event_id , location_id , location_name , empire_id , empire_name )
VALUES ( evt_id , p_id , p_name , oo_id , oo_name );
END;
$$ LANGUAGE plpgsql;
--
-- Creates an event for planet abandon
--
-- Parameters:
-- p_id Planet identifier
--
CREATE OR REPLACE FUNCTION events.planet_abandon_event( p_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
p_name VARCHAR(20);
po_id INT;
oo_name VARCHAR(20);
evt_id BIGINT;
BEGIN
-- Get owner's ID and planet's name
SELECT INTO p_name , po_id n.name , ep.empire_id
FROM naming.map_names n
INNER JOIN emp.planets ep ON ep.planet_id = n.id
WHERE n.id = p_id;
-- Add abandon event
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( po_id , sys.get_tick( ) - 1 , 'PLANET' , 5 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.planet_events ( event_id , location_id , location_name )
VALUES ( evt_id , p_id , p_name );
END;
$$ LANGUAGE plpgsql;
--
-- Creates an event for a technology's availability
--
-- Parameters:
-- e_id Empire identifier
-- t_id Technology identifier
--
CREATE OR REPLACE FUNCTION events.tech_ready_event( e_id INT , t_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
evt_id BIGINT;
BEGIN
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( e_id , sys.get_tick( ) - 1 , 'EMPIRE' , 0 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.empire_events ( event_id , technology_id )
VALUES ( evt_id , t_id );
END;
$$ LANGUAGE plpgsql;
--
-- Creates an event for start/end of debt
--
-- Parameters:
-- e_id Empire identifier
-- sevt Whether this is the start or the end
--
CREATE OR REPLACE FUNCTION events.debt_event( e_id INT , sevt BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( $1 , sys.get_tick( ) - 1 , 'EMPIRE' , ( CASE WHEN $2 THEN 1 ELSE 2 END ) , 'READY' );
$$ LANGUAGE SQL;
--
-- Creates a "pending request" event
--
-- Parameters:
-- a_id Alliance identifier
-- e_id Empire identifier
--
CREATE OR REPLACE FUNCTION events.alliance_request_event( a_id INT , e_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
a_tag TEXT;
al_id INT;
e_name TEXT;
evt_id BIGINT;
BEGIN
-- Get the alliance's name and leader ID
SELECT INTO a_tag , al_id tag , leader_id FROM emp.alliances WHERE id = a_id;
-- Get the joining player's name
SELECT INTO e_name name FROM naming.empire_names WHERE id = e_id;
-- Create the event
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( al_id , sys.get_tick( ) , 'ALLIANCE' , 0 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag , empire_id , empire_name )
VALUES ( evt_id , a_id , a_tag , e_id , e_name );
END;
$$ LANGUAGE plpgsql;
--
-- Creates a request validation/rejection event
--
-- Parameters:
-- a_id Alliance identifier
-- e_id Empire identifier
-- acc Whether the request was accepted or rejected
--
CREATE OR REPLACE FUNCTION events.alliance_response_event( a_id INT , e_id INT , acc BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
a_tag TEXT;
e_name TEXT;
evt_id BIGINT;
BEGIN
-- Get the alliance's name and leader ID
SELECT INTO a_tag tag FROM emp.alliances WHERE id = a_id;
-- Get the requesting player's name
SELECT INTO e_name name FROM naming.empire_names WHERE id = e_id;
-- Create the event
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( e_id , sys.get_tick( ) , 'ALLIANCE' , 1 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag , req_result )
VALUES ( evt_id , a_id , a_tag , acc );
END;
$$ LANGUAGE plpgsql;
--
-- Creates a leadership change event
--
-- Parameters:
-- a_id Alliance identifier
-- ol_id Previous leader's identifier
--
CREATE OR REPLACE FUNCTION events.alliance_lchange_event( a_id INT , ol_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
a_tag TEXT;
al_id INT;
al_name TEXT;
am_id INT;
evt_id BIGINT;
BEGIN
-- Get alliance tag, leader ID and leader name
SELECT INTO a_tag , al_id , al_name a.tag , a.leader_id , n.name
FROM emp.alliances a
INNER JOIN naming.empire_names n ON n.id = a.leader_id
WHERE a.id = a_id;
-- Notify both members and pending members
FOR am_id IN SELECT empire_id FROM emp.alliance_members
WHERE alliance_id = a_id AND empire_id <> ol_id
LOOP
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( am_id , sys.get_tick( ) , 'ALLIANCE' , 2 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag , empire_id , empire_name )
VALUES ( evt_id , a_id , a_tag , al_id , al_name );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Creates an alliance kick event
--
-- Parameters:
-- a_id Alliance identifier
-- ol_id Member being kicked
--
CREATE OR REPLACE FUNCTION events.alliance_kick_event( a_id INT , k_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
a_tag TEXT;
al_id INT;
k_name TEXT;
am_id INT;
evt_id BIGINT;
BEGIN
-- Get alliance tag and leader ID
SELECT INTO a_tag , al_id a.tag , a.leader_id
FROM emp.alliances a
INNER JOIN naming.empire_names n ON n.id = a.leader_id
WHERE a.id = a_id;
SELECT INTO k_name name FROM naming.empire_names WHERE id = k_id;
-- Notify members
FOR am_id IN SELECT empire_id FROM emp.alliance_members
WHERE alliance_id = a_id AND empire_id <> al_id AND NOT is_pending
LOOP
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( am_id , sys.get_tick( ) , 'ALLIANCE' , 3 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag , empire_id , empire_name )
VALUES ( evt_id , a_id , a_tag , k_id , k_name );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Creates an alliance quit event
--
-- Parameters:
-- a_id Alliance identifier
-- q_id Member quitting the alliance
--
CREATE OR REPLACE FUNCTION events.alliance_quit_event( a_id INT , q_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
a_tag TEXT;
q_name TEXT;
am_id INT;
evt_id BIGINT;
BEGIN
-- Get alliance tag and quitter name
SELECT INTO a_tag a.tag FROM emp.alliances a WHERE a.id = a_id;
SELECT INTO q_name name FROM naming.empire_names WHERE id = q_id;
-- Notify members
FOR am_id IN SELECT empire_id FROM emp.alliance_members
WHERE alliance_id = a_id AND NOT is_pending
LOOP
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( am_id , sys.get_tick( ) , 'ALLIANCE' , 4 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag , empire_id , empire_name )
VALUES ( evt_id , a_id , a_tag , q_id , q_name );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Creates an alliance disband event
--
-- Parameters:
-- a_id Alliance identifier
-- q_id Member quitting the alliance
--
CREATE OR REPLACE FUNCTION events.alliance_disband_event( a_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
a_tag TEXT;
al_id INT;
am_id INT;
evt_id BIGINT;
BEGIN
-- Get alliance tag and quitter name
SELECT INTO a_tag , al_id a.tag , leader_id FROM emp.alliances a WHERE a.id = a_id;
-- Notify members
FOR am_id IN SELECT empire_id FROM emp.alliance_members
WHERE alliance_id = a_id AND empire_id <> al_id
LOOP
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( am_id , sys.get_tick( ) , 'ALLIANCE' , 5 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.alliance_events ( event_id , alliance_id , alliance_tag )
VALUES ( evt_id , a_id , a_tag );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Creates empty build queue events or updates existing ones
--
-- Parameters:
-- e_id Empire identifier
-- p_id Planet identifier
-- mqueue Whether the empty queue is the military or civilian queue
-- c_tick Current tick
--
CREATE OR REPLACE FUNCTION events.empty_queue_events( e_id INT , p_id INT , mqueue BOOLEAN , c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
evt_st INT;
evt_id BIGINT;
p_name TEXT;
BEGIN
evt_st := ( CASE WHEN mqueue THEN 1 ELSE 0 END );
SELECT INTO evt_id event_id FROM events.events
WHERE evt_type = 'QUEUE' AND evt_subtype = evt_st
AND empire_id = e_id AND tick = c_tick;
IF NOT FOUND
THEN
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( e_id , c_tick , 'QUEUE' , evt_st , 'TICK' )
RETURNING event_id INTO evt_id;
INSERT INTO events.queue_events VALUES ( evt_id );
END IF;
SELECT INTO p_name name FROM naming.map_names WHERE id = p_id;
INSERT INTO events.bqe_locations VALUES ( evt_id , p_id , p_name );
END;
$$ LANGUAGE plpgsql;
--
-- Commits fleet arrival events from the "fleet_arrivals" temporary table
--
-- Parameters:
-- c_tick Current tick identifier
--
CREATE OR REPLACE FUNCTION events.commit_fleet_arrivals( c_tick BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
l_id INT;
l_name TEXT;
tg_id INT;
tg_mode BOOLEAN;
evt_id BIGINT;
BEGIN
FOR l_id , l_name , tg_id , tg_mode
IN SELECT DISTINCT a.loc_id , a.loc_name , l.empire , l.attacking
FROM fleet_arrivals a
INNER JOIN fleets.locations_list_view l ON l.location = a.loc_id
LOOP
-- Create event record
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( tg_id , c_tick , 'FLEETS' , 0 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.fleets_events( event_id , location_id , location_name )
VALUES ( evt_id , l_id , l_name );
-- List fleets
INSERT INTO events.fleet_lists ( event_id , owner_id , owner_name , fleet_name , fleet_power , status , source_id , source_name )
SELECT evt_id , a.own_id , a.own_name , a.name , a.power , ( CASE
WHEN tg_id = a.own_id
THEN tg_mode
ELSE
( tg_mode <> a.mode )
END ) , a.src_id , a.src_name
FROM fleet_arrivals a
WHERE loc_id = l_id
ORDER BY ( a.own_id = tg_id ) DESC , a.mode , own_name , name NULLS LAST;
END LOOP;
DROP TABLE fleet_arrivals;
END;
$$ LANGUAGE plpgsql;
--
-- Commits fleet departure events from the "fleet_departures" temporary table
--
CREATE OR REPLACE FUNCTION events.commit_fleet_departures( )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
l_id INT;
l_name TEXT;
tg_id INT;
tg_mode BOOLEAN;
evt_id BIGINT;
c_tick BIGINT;
BEGIN
c_tick := sys.get_tick( );
FOR l_id , l_name , tg_id , tg_mode
IN SELECT DISTINCT a.loc_id , a.loc_name , l.empire , l.attacking
FROM fleet_departures a
INNER JOIN fleets.locations_list_view l
ON l.location = a.loc_id AND l.empire <> a.own_id
LOOP
-- Create event record
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( tg_id , c_tick , 'FLEETS' , 1 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.fleets_events( event_id , location_id , location_name )
VALUES ( evt_id , l_id , l_name );
-- List fleets
INSERT INTO events.fleet_lists ( event_id , owner_id , owner_name , fleet_name , fleet_power , status )
SELECT evt_id , a.own_id , a.own_name , a.name , a.power , ( tg_mode <> a.mode )
FROM fleet_departures a
WHERE loc_id = l_id AND own_id <> tg_id
ORDER BY a.mode , own_name , name NULLS LAST;
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Commits fleet mode change events from the "fleet_switches" temporary table
--
-- Parameters:
-- els Whether the switch was caused through the enemy list
--
CREATE OR REPLACE FUNCTION events.commit_fleet_switches( els BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
l_id INT;
l_name TEXT;
tg_id INT;
tg_mode BOOLEAN;
evt_id BIGINT;
c_tick BIGINT;
own_c BIGINT;
other_c BIGINT;
BEGIN
c_tick := sys.get_tick( );
FOR l_id , l_name , tg_id , tg_mode
IN SELECT DISTINCT a.loc_id , a.loc_name , l.empire , l.attacking
FROM fleet_switches a
INNER JOIN fleets.locations_list_view l
ON l.location = a.loc_id
LOOP
-- Handle other fleets
SELECT INTO other_c count(*) FROM fleet_switches WHERE loc_id = l_id AND own_id <> tg_id;
IF other_c > 0
THEN
-- Create event record
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( tg_id , c_tick , 'FLEETS' , 2 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.fleets_events( event_id , location_id , location_name )
VALUES ( evt_id , l_id , l_name );
-- List fleets
INSERT INTO events.fleet_lists ( event_id , owner_id , owner_name , fleet_name , fleet_power , status )
SELECT evt_id , a.own_id , a.own_name , a.name , a.power , a.mode
FROM fleet_switches a
WHERE loc_id = l_id AND own_id <> tg_id
ORDER BY a.mode , own_name , name NULLS LAST;
END IF;
-- Handle own fleets
CONTINUE WHEN NOT els;
SELECT INTO own_c count(*) FROM fleet_switches WHERE loc_id = l_id AND own_id = tg_id;
CONTINUE WHEN own_c = 0;
-- Create event record
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( tg_id , c_tick , 'FLEETS' , 3 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.fleets_events( event_id , location_id , location_name )
VALUES ( evt_id , l_id , l_name );
-- List fleets
INSERT INTO events.fleet_lists ( event_id , owner_id , owner_name , fleet_name , fleet_power , status )
SELECT evt_id , a.own_id , a.own_name , a.name , a.power , a.mode
FROM fleet_switches a
WHERE loc_id = l_id AND own_id = tg_id
ORDER BY a.mode , own_name , name NULLS LAST;
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Creates a map name rejection event
--
-- Parameters:
-- u_id Account identifier
-- n_id Name identifier
-- o_name Old name
-- n_name New name
-- w_sent Whether a warning was sent
-- w_count Current warnings
--
CREATE OR REPLACE FUNCTION events.map_name_rejected_event( u_id INT , n_id INT , o_name TEXT , n_name TEXT , w_sent BOOLEAN , w_count INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
e_id INT;
evt_id BIGINT;
BEGIN
-- Get empire identifier
SELECT INTO e_id e.name_id
FROM emp.empires e
INNER JOIN naming.empire_names en ON en.id = e.name_id
WHERE en.owner_id = u_id;
IF NOT FOUND
THEN
RETURN;
END IF;
-- Add event
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( e_id , sys.get_tick( ) - 1 , 'ADMIN' , 0 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.admin_events( event_id , n_warnings , location_id , old_name , new_name )
VALUES( evt_id , ( CASE WHEN w_sent THEN w_count ELSE NULL END ) , n_id , o_name , n_name );
END;
$$ LANGUAGE plpgsql;
--
-- Creates an empire name rejection event
--
-- Parameters:
-- n_id Name identifier
-- o_name Old name
-- n_name New name
-- w_sent Whether a warning was sent
-- w_count Current warnings
--
CREATE OR REPLACE FUNCTION events.empire_name_rejected_event( n_id INT , o_name TEXT , n_name TEXT , w_sent BOOLEAN , w_count INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
evt_id BIGINT;
BEGIN
-- Add event
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( n_id , sys.get_tick( ) - 1 , 'ADMIN' , 1 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.admin_events( event_id , n_warnings ,old_name , new_name )
VALUES( evt_id , ( CASE WHEN w_sent THEN w_count ELSE NULL END ) , o_name , n_name );
END;
$$ LANGUAGE plpgsql;
--
-- Creates an alliance name rejection event
--
-- Parameters:
-- n_id Empire identifier
-- o_name Alliance name
-- w_sent Whether a warning was sent
-- w_count Current warnings
--
CREATE OR REPLACE FUNCTION events.alliance_name_rejected_event( n_id INT , o_name TEXT , w_sent BOOLEAN , w_count INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
evt_id BIGINT;
BEGIN
-- Add event
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( n_id , sys.get_tick( ) - 1 , 'ADMIN' , 2 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.admin_events( event_id , n_warnings , old_name )
VALUES( evt_id , ( CASE WHEN w_sent THEN w_count ELSE NULL END ) , o_name );
END;
$$ LANGUAGE plpgsql;
--
-- Creates events for updated bug reports
--
-- Parameters:
-- e_id Empire identifier
-- br_id Bug report identifier
-- s_id Submitter identifier
--
CREATE OR REPLACE FUNCTION events.bug_report_updated_event( e_id INT , br_id BIGINT , s_id BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
evt_id BIGINT;
BEGIN
INSERT INTO events.events ( empire_id , tick , evt_type , evt_subtype , status )
VALUES ( e_id , sys.get_tick( ) - 1 , 'BUGS' , 0 , 'READY' )
RETURNING event_id INTO evt_id;
INSERT INTO events.bug_events( event_id , bug_id , submitter_id )
VALUES ( evt_id , br_id , s_id );
END;
$$ LANGUAGE plpgsql;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- EVENTS VIEWS, USED BY THE MESSAGE SYSTEM --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Main events lists
--
CREATE VIEW events.queue_events_view
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time , ed.*
FROM events.events e
INNER JOIN events.queue_events ed USING (event_id);
GRANT SELECT ON events.queue_events_view TO :dbuser;
CREATE VIEW events.empire_events_view
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time , s.name AS technology
FROM events.events e
LEFT OUTER JOIN events.empire_events ed USING (event_id)
LEFT OUTER JOIN tech.technologies tl ON tl.name_id = ed.technology_id
LEFT OUTER JOIN defs.strings s ON s.id = tl.name_id
WHERE e.evt_type = 'EMPIRE';
GRANT SELECT ON events.empire_events_view TO :dbuser;
CREATE VIEW events.fleets_events_view
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time ,
ed.* , s.x , s.y , p.orbit
FROM events.events e
INNER JOIN events.fleets_events ed USING (event_id)
INNER JOIN verse.planets p ON p.name_id = ed.location_id
INNER JOIN verse.systems s ON s.id = p.system_id;
GRANT SELECT ON events.fleets_events_view TO :dbuser;
CREATE VIEW events.planet_events_view
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time ,
ed.* , s.x , s.y , p.orbit
FROM events.events e
INNER JOIN events.planet_events ed USING (event_id)
INNER JOIN verse.planets p ON p.name_id = ed.location_id
INNER JOIN verse.systems s ON s.id = p.system_id;
GRANT SELECT ON events.planet_events_view TO :dbuser;
CREATE VIEW events.alliance_events_view
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time , ed.*
FROM events.events e
INNER JOIN events.alliance_events ed USING (event_id);
GRANT SELECT ON events.alliance_events_view TO :dbuser;
CREATE VIEW events.admin_events_view
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time , ed.*
FROM events.events e
INNER JOIN events.admin_events ed USING ( event_id );
GRANT SELECT ON events.admin_events_view TO :dbuser;
CREATE VIEW events.bugs_events_view
AS SELECT e.event_id AS id , e.evt_type , e.evt_subtype , e.tick , e.real_time , ed.bug_id ,
bs.is_admin AS submitter_admin , bs.name AS submitter_name
FROM events.events e
INNER JOIN events.bug_events ed USING ( event_id )
INNER JOIN bugs.submitters bs USING ( submitter_id );
GRANT SELECT ON events.bugs_events_view TO :dbuser;
--
-- Queue event locations
--
CREATE VIEW events.queue_locations_view
AS SELECT bqe.* , s.x , s.y , p.orbit
FROM events.bqe_locations bqe
INNER JOIN verse.planets p ON p.name_id = bqe.location_id
INNER JOIN verse.systems s ON s.id = p.system_id;
GRANT SELECT ON events.queue_locations_view TO :dbuser;