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/200-bugs-functions.sql

1283 lines
No EOL
40 KiB
PL/PgSQL

-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Bug tracking system functions and views
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- HELPER FUNCTIONS --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Creates or gets a submitter from an administrator
--
-- Parameters:
-- a_id Administrator identifier
--
-- Returns:
-- s_id The submitter record's identifier
--
CREATE OR REPLACE FUNCTION bugs.goc_admin_submitter( a_id INT , OUT s_id BIGINT )
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
a_name TEXT;
BEGIN
a_name := NULL;
LOOP
-- Try finding an existing record
SELECT INTO s_id s.submitter_id
FROM bugs.submitters s
INNER JOIN bugs.admin_submitters a USING ( submitter_id )
WHERE a.admin_id = a_id;
EXIT WHEN FOUND;
-- Try creating the admin submitter
IF a_name IS NULL
THEN
SELECT INTO a_name appear_as FROM admin.administrators WHERE id = a_id;
END IF;
INSERT INTO bugs.submitters ( is_admin , name )
VALUES ( TRUE , a_name)
RETURNING submitter_id INTO s_id;
BEGIN
INSERT INTO bugs.admin_submitters ( submitter_id , admin_id )
VALUES ( s_id , a_id );
EXIT;
EXCEPTION
WHEN unique_violation THEN
DELETE FROM bugs.submitters WHERE id = s_id;
END;
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Gets a submitter from an empire identifier
--
-- Parameters:
-- e_id Empire identifier
--
-- Returns:
-- s_id The submitter record's identifier
--
CREATE OR REPLACE FUNCTION bugs.get_user_submitter( e_id INT )
RETURNS BIGINT
STRICT STABLE
SECURITY INVOKER
AS $$
SELECT s.submitter_id
FROM emp.empires e
INNER JOIN naming.empire_names en ON en.id = e.name_id
INNER JOIN bugs.user_submitters s ON s.account_id = en.owner_id
WHERE e.name_id = $1;
$$ LANGUAGE SQL;
--
-- Creates or gets a submitter from an empire identifier
--
-- Parameters:
-- e_id Empire identifier
--
-- Returns:
-- s_id The submitter record's identifier
--
CREATE OR REPLACE FUNCTION bugs.goc_user_submitter( e_id INT , OUT s_id BIGINT )
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
a_id INT;
a_name TEXT;
BEGIN
SELECT INTO a_id , a_name ac.credentials_id , en.name
FROM emp.empires e
INNER JOIN naming.empire_names en ON en.id = e.name_id
INNER JOIN users.active_accounts ac ON ac.credentials_id = en.owner_id
WHERE e.name_id = e_id;
LOOP
-- Try finding an existing record
SELECT INTO s_id s.submitter_id
FROM bugs.submitters s
INNER JOIN bugs.user_submitters a USING ( submitter_id )
WHERE a.account_id = a_id;
EXIT WHEN FOUND;
-- Try creating the submitter
INSERT INTO bugs.submitters ( is_admin , name )
VALUES ( FALSE , a_name)
RETURNING submitter_id INTO s_id;
BEGIN
INSERT INTO bugs.user_submitters ( submitter_id , account_id )
VALUES ( s_id , a_id );
EXIT;
EXCEPTION
WHEN unique_violation THEN
DELETE FROM bugs.submitters WHERE id = s_id;
END;
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Posts a new bug report
--
-- Parameters:
-- is_admin Whether the specified identifier corresponds to an administrator or to an empire
-- u_id User identifier
-- r_ttl Bug report title
-- r_desc Bug description
--
-- Returns:
-- br_id The bug report's identifier
-- bg_id The bug report's group identifier
--
CREATE OR REPLACE FUNCTION bugs.post_report( is_admin BOOLEAN , u_id INT , r_ttl TEXT , r_desc TEXT , OUT br_id BIGINT , OUT bg_id BIGINT )
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
sub_id BIGINT;
BEGIN
-- Get the submitter's identifier
IF is_admin
THEN
sub_id := bugs.goc_admin_submitter( u_id );
ELSE
sub_id := bugs.goc_user_submitter( u_id );
END IF;
-- Create the bug report's group
INSERT INTO bugs.groups DEFAULT VALUES
RETURNING group_id INTO bg_id;
-- Post the initial report
INSERT INTO bugs.events ( group_id , submitter_id , e_type )
VALUES ( bg_id , sub_id , 'INIT' )
RETURNING event_id INTO br_id;
INSERT INTO bugs.initial_report_events ( event_id , title , description )
VALUES ( br_id , r_ttl , r_desc );
END;
$$ LANGUAGE plpgsql;
--
-- Sends an internal message to all user submitters
--
CREATE OR REPLACE FUNCTION bugs.update_notification( br_id BIGINT , sub_id BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
grp_id BIGINT;
oe_id INT;
obr_id BIGINT;
BEGIN
-- Get the report's group id
SELECT INTO grp_id group_id FROM bugs.events WHERE event_id = br_id;
-- Find user submitters and send them a message
FOR oe_id , obr_id IN SELECT DISTINCT mv.empire_id , mv.bug_report_id
FROM bugs.br_user_view mv
INNER JOIN naming.empire_names en ON en.id = mv.empire_id
INNER JOIN bugs.user_submitters us ON us.account_id = en.owner_id
INNER JOIN bugs.events evt
ON evt.submitter_id = us.submitter_id AND evt.group_id = mv.group_id
WHERE mv.group_id = grp_id AND NOT mv.updated AND us.submitter_id <> sub_id
LOOP
PERFORM events.bug_report_updated_event( oe_id , obr_id , sub_id );
PERFORM msgs.deliver_internal( oe_id );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Sends an internal message to all user submitters for TWO bug reports (used when merging)
--
CREATE OR REPLACE FUNCTION bugs.update_notification( br1_id BIGINT , br2_id BIGINT , sub_id BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
grp1_id BIGINT;
grp2_id BIGINT;
oe_id INT;
obr_id BIGINT;
BEGIN
-- Get the report's group id
SELECT INTO grp1_id group_id FROM bugs.events WHERE event_id = br1_id;
SELECT INTO grp2_id group_id FROM bugs.events WHERE event_id = br2_id;
-- Find user submitters and send them a message
FOR oe_id , obr_id IN SELECT DISTINCT mv.empire_id , mv.bug_report_id
FROM bugs.br_user_view mv
INNER JOIN naming.empire_names en ON en.id = mv.empire_id
INNER JOIN bugs.user_submitters us ON us.account_id = en.owner_id
INNER JOIN bugs.events evt
ON evt.submitter_id = us.submitter_id AND evt.group_id = mv.group_id
WHERE mv.group_id IN ( grp1_id , grp2_id ) AND NOT mv.updated AND us.submitter_id <> sub_id
LOOP
PERFORM events.bug_report_updated_event( oe_id , obr_id , sub_id );
PERFORM msgs.deliver_internal( oe_id );
END LOOP;
END;
$$ LANGUAGE plpgsql;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- VIEWS USED TO ACCESS BUG REPORTS --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
CREATE VIEW bugs.br_groups
AS SELECT group_id , event_id AS bug_report_id , submitter_id AS initial_submitter_id
FROM bugs.events
INNER JOIN bugs.initial_report_events USING ( event_id );
CREATE VIEW bugs.br_first_report
AS SELECT group_id , min( bug_report_id ) AS bug_report_id
FROM bugs.br_groups
GROUP BY group_id;
GRANT SELECT ON bugs.br_first_report TO :dbuser;
CREATE VIEW bugs.br_first_submitter_report
AS SELECT group_id , initial_submitter_id , min( bug_report_id ) AS bug_report_id
FROM bugs.br_groups
GROUP BY group_id , initial_submitter_id;
CREATE VIEW bugs.br_group_submitters
AS SELECT DISTINCT group_id , submitter_id FROM bugs.events;
CREATE VIEW bugs.br_submitters
AS SELECT submitter_id , is_admin , name ,
( CASE
WHEN is_admin THEN admin_id
ELSE account_id
END ) AS user_id
FROM bugs.submitters
LEFT OUTER JOIN bugs.admin_submitters USING (submitter_id)
LEFT OUTER JOIN bugs.user_submitters USING (submitter_id);
CREATE VIEW bugs.br_updates
AS SELECT group_id , max(event_id) AS last_update_id
FROM bugs.events
GROUP BY group_id;
CREATE VIEW bugs.br_user_updates
AS SELECT group_id , max(event_id) AS last_update_id
FROM bugs.events
LEFT OUTER JOIN bugs.comment_events USING( event_id )
WHERE visible IS NULL OR visible
GROUP BY group_id;
CREATE VIEW bugs.br_update_types
AS SELECT group_id , e_type , max( event_id ) AS last_event_id
FROM bugs.events
GROUP BY group_id , e_type;
CREATE VIEW bugs.br_status
AS SELECT g.group_id ,
( CASE
WHEN u.last_event_id IS NULL THEN 'PENDING'::TEXT
ELSE s.status::TEXT
END ) AS status
FROM bugs.groups g
LEFT OUTER JOIN bugs.br_update_types u
ON u.group_id = g.group_id AND u.e_type = 'STATUS'
LEFT OUTER JOIN bugs.status_change_events s ON s.event_id = u.last_event_id;
GRANT SELECT ON bugs.br_status TO :dbuser;
CREATE VIEW bugs.br_visibility
AS SELECT g.group_id ,
( CASE
WHEN u.last_event_id IS NULL THEN FALSE
ELSE v.visible
END ) AS visible
FROM bugs.groups g
LEFT OUTER JOIN bugs.br_update_types u
ON u.group_id = g.group_id AND u.e_type = 'VISIBILITY'
LEFT OUTER JOIN bugs.visibility_events v ON v.event_id = u.last_event_id;
CREATE VIEW bugs.br_main_view
AS SELECT fr.group_id , v.visible , s.status , lue.t AS last_update ,
lus.is_admin AS last_submitter_admin , lus.name AS last_submitter_name , lus.user_id AS last_submitter_uid
FROM bugs.br_first_report fr
INNER JOIN bugs.br_visibility v ON v.group_id = fr.group_id
INNER JOIN bugs.br_status s ON s.group_id = fr.group_id
INNER JOIN bugs.br_updates lu ON lu.group_id = fr.group_id
INNER JOIN bugs.events lue ON lue.event_id = lu.last_update_id
INNER JOIN bugs.br_submitters lus ON lus.submitter_id = lue.submitter_id;
CREATE VIEW bugs.br_main_user_view
AS SELECT fr.group_id , v.visible , s.status , lue.t AS last_update ,
lus.is_admin AS last_submitter_admin , lus.name AS last_submitter_name , lus.user_id AS last_submitter_uid
FROM bugs.br_first_report fr
INNER JOIN bugs.br_visibility v ON v.group_id = fr.group_id
INNER JOIN bugs.br_status s ON s.group_id = fr.group_id
INNER JOIN bugs.br_user_updates lu ON lu.group_id = fr.group_id
INNER JOIN bugs.events lue ON lue.event_id = lu.last_update_id
INNER JOIN bugs.br_submitters lus ON lus.submitter_id = lue.submitter_id;
--
-- Main view for administrators
--
CREATE VIEW bugs.br_admin_view
AS SELECT a.id AS administrator_id , mv.group_id ,
ire.event_id AS bug_report_id , mv.visible , mv.status , ire.t AS posted , ir.title AS title ,
isb.is_admin AS initial_submitter_admin , isb.name AS initial_submitter_name , isb.user_id AS initial_submitter_uid ,
mv.last_update , mv.last_submitter_admin , mv.last_submitter_name , mv.last_submitter_uid ,
( CASE
WHEN mv.status NOT IN ('PENDING','OPEN') THEN FALSE
WHEN avs.last_view IS NULL THEN TRUE
ELSE ( avs.last_view < mv.last_update )
END ) AS updated ,
( bg.bug_report_id IS NOT NULL ) AS own_report
FROM admin.administrators a
CROSS JOIN bugs.br_main_view mv
LEFT OUTER JOIN bugs.admin_view_status avs
ON avs.admin_id = a.id AND avs.group_id = mv.group_id
INNER JOIN bugs.br_first_report fr ON fr.group_id = mv.group_id
LEFT OUTER JOIN bugs.admin_submitters asb ON asb.admin_id = a.id
LEFT OUTER JOIN bugs.br_first_submitter_report bg
ON bg.group_id = mv.group_id AND bg.initial_submitter_id = asb.submitter_id
INNER JOIN bugs.events ire ON ire.event_id = ( CASE
WHEN bg.bug_report_id IS NULL THEN fr.bug_report_id
ELSE bg.bug_report_id
END )
INNER JOIN bugs.initial_report_events ir ON ir.event_id = ire.event_id
INNER JOIN bugs.br_submitters isb ON isb.submitter_id = ire.submitter_id;
GRANT SELECT ON bugs.br_admin_view TO :dbuser;
--
-- Main view for users
--
CREATE VIEW bugs.br_user_view
AS SELECT e.name_id AS empire_id , mv.group_id ,
ire.event_id AS bug_report_id , mv.visible , mv.status , ire.t AS posted , ir.title AS title ,
isb.is_admin AS initial_submitter_admin , isb.name AS initial_submitter_name , isb.user_id AS initial_submitter_uid ,
mv.last_update , mv.last_submitter_admin , mv.last_submitter_name , mv.last_submitter_uid ,
( CASE
WHEN uvs.last_view IS NULL THEN FALSE
ELSE ( uvs.last_view < mv.last_update )
END ) AS updated ,
( bg.bug_report_id IS NOT NULL ) AS own_report
FROM emp.empires e
INNER JOIN naming.empire_names en ON en.id = e.name_id
CROSS JOIN bugs.br_main_user_view mv
LEFT OUTER JOIN bugs.user_view_status uvs
ON uvs.user_id = en.owner_id AND uvs.group_id = mv.group_id
INNER JOIN bugs.br_first_report fr ON fr.group_id = mv.group_id
LEFT OUTER JOIN bugs.user_submitters usb ON usb.account_id = en.owner_id
LEFT OUTER JOIN bugs.br_first_submitter_report bg
ON bg.group_id = mv.group_id AND bg.initial_submitter_id = usb.submitter_id
INNER JOIN bugs.events ire ON ire.event_id = ( CASE
WHEN bg.bug_report_id IS NULL THEN fr.bug_report_id
ELSE bg.bug_report_id
END )
INNER JOIN bugs.initial_report_events ir ON ir.event_id = ire.event_id
INNER JOIN bugs.br_submitters isb ON isb.submitter_id = ire.submitter_id
LEFT OUTER JOIN bugs.br_group_submitters gs
ON gs.submitter_id = usb.submitter_id AND gs.group_id = mv.group_id
WHERE gs.submitter_id IS NOT NULL OR ( mv.visible AND mv.status <> 'PENDING' );
GRANT SELECT ON bugs.br_user_view TO :dbuser;
--
-- Bug events view
--
CREATE VIEW bugs.br_events
AS SELECT ir.event_id AS bug_report_id ,
evt.event_id AS event_id , evt.e_type AS event_type , evt.t AS event_timestamp ,
es.name AS submitter_name , es.is_admin AS submitter_admin ,
( CASE WHEN es.is_admin THEN asb.admin_id ELSE usb.account_id END ) AS submitter_uid ,
tir.title AS title ,
( CASE WHEN evt.e_type = 'INIT' THEN tir.description ELSE tc.comment END ) AS contents ,
tm.initial_post_id AS merged_report_id ,
ts.status AS status ,
( CASE
WHEN evt.e_type = 'COMMENT' THEN tc.visible
WHEN evt.e_type = 'INIT' THEN ( asd IS NOT NULL )
ELSE tv.visible
END ) AS visible
FROM bugs.initial_report_events ir
INNER JOIN bugs.events ire ON ire.event_id = ir.event_id
INNER JOIN bugs.events evt ON evt.group_id = ire.group_id
INNER JOIN bugs.submitters es ON es.submitter_id = evt.submitter_id
LEFT OUTER JOIN bugs.admin_submitters asb ON asb.submitter_id = es.submitter_id
LEFT OUTER JOIN bugs.user_submitters usb ON usb.submitter_id = es.submitter_id
LEFT OUTER JOIN bugs.initial_report_events tir ON tir.event_id = evt.event_id
LEFT OUTER JOIN bugs.account_status_data asd ON asd.event_id = tir.event_id
LEFT OUTER JOIN bugs.comment_events tc ON tc.event_id = evt.event_id
LEFT OUTER JOIN bugs.merge_events tm ON tm.event_id = evt.event_id
LEFT OUTER JOIN bugs.status_change_events ts ON ts.event_id = evt.event_id
LEFT OUTER JOIN bugs.visibility_events tv ON tv.event_id = evt.event_id
ORDER BY evt.t;
GRANT SELECT ON bugs.br_events TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- FUNCTIONS THAT HANDLE PLAYER ACCESS TO BUG REPORTS --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Posts a new bug report, including additional data
--
-- Parameters:
-- e_id Empire identifier
-- r_ttl Report title
-- r_desc Bug description
-- e_data Extended data to associate with the post
--
-- Returns:
-- br_id The bug report's identifier
-- bg_id The bug report's group
--
CREATE OR REPLACE FUNCTION bugs.post_player_report( e_id INT , r_ttl TEXT , r_desc TEXT , e_data TEXT , OUT br_id BIGINT , OUT bg_id BIGINT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
SELECT INTO br_id , bg_id * FROM bugs.post_report( FALSE , e_id , r_ttl , r_desc );
IF e_data <> ''
THEN
INSERT INTO bugs.account_status_data( event_id , account_status )
VALUES ( br_id , e_data );
END IF;
INSERT INTO bugs.user_view_status ( group_id , user_id )
SELECT bg_id , n.owner_id
FROM naming.empire_names n
WHERE n.id = e_id;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION bugs.post_player_report( INT , TEXT , TEXT , TEXT ) TO :dbuser;
--
-- Posts a comment on an existing bug report
--
-- Parameters:
-- e_id Empire identifier
-- br_id Bug report identifier
-- c_txt Comment to post
--
CREATE OR REPLACE FUNCTION bugs.post_player_comment( e_id INT , br_id BIGINT , c_txt TEXT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
sub_id BIGINT;
grp_id BIGINT;
cmt_id BIGINT;
oe_id INT;
obr_id BIGINT;
BEGIN
-- Get submitter
sub_id := bugs.get_user_submitter( e_id );
IF sub_id IS NULL
THEN
RETURN;
END IF;
-- Is submitter associated with this bug report?
SELECT INTO grp_id group_id
FROM bugs.br_groups
INNER JOIN bugs.br_group_submitters USING (group_id)
INNER JOIN bugs.br_status USING (group_id)
WHERE bug_report_id = br_id
AND ( status = 'PENDING' AND initial_submitter_id = sub_id
OR status = 'OPEN' AND submitter_id = sub_id );
IF NOT FOUND
THEN
RETURN;
END IF;
-- Insert comment
INSERT INTO bugs.events ( group_id , submitter_id , e_type )
VALUES ( grp_id , sub_id , 'COMMENT' )
RETURNING event_id INTO cmt_id;
INSERT INTO bugs.comment_events ( event_id , comment , visible )
VALUES ( cmt_id , c_txt , FALSE );
-- Update view status
UPDATE bugs.user_view_status v SET last_view = now( )
FROM naming.empire_names en
WHERE en.id = e_id AND v.user_id = en.owner_id AND v.group_id = grp_id;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION bugs.post_player_comment( INT , BIGINT , TEXT ) TO :dbuser;
--
-- Reads a bug report
--
-- Parameters:
-- e_id Empire identifier
-- br_id Bug report to read
--
-- Returns:
-- The bug report as descibed by bugs.br_user_view
--
CREATE OR REPLACE FUNCTION bugs.read_player_report( e_id INT , br_id BIGINT )
RETURNS SETOF bugs.br_user_view
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
rec bugs.br_user_view;
BEGIN
SELECT INTO rec mv.* FROM bugs.br_user_view mv
INNER JOIN bugs.br_groups bg USING ( group_id )
WHERE mv.empire_id = e_id AND bg.bug_report_id = br_id;
IF FOUND
THEN
LOOP
UPDATE bugs.user_view_status vs SET last_view = now( )
FROM bugs.br_groups bg , naming.empire_names en
WHERE bg.bug_report_id = br_id AND en.id = e_id
AND vs.group_id = bg.group_id AND vs.user_id = en.owner_id;
EXIT WHEN FOUND;
BEGIN
INSERT INTO bugs.user_view_status ( group_id , user_id )
SELECT bg.group_id , en.owner_id
FROM bugs.br_groups bg , naming.empire_names en
WHERE bug_report_id = br_id AND en.id = e_id;
EXIT;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
END LOOP;
RETURN NEXT rec;
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION bugs.read_player_report( INT , BIGINT ) TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- FUNCTIONS THAT HANDLE ADMIN ACCESS TO BUG REPORTS --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Posts a new bug report
--
-- Parameters:
-- a_id Admin identifier
-- r_ttl Report title
-- r_desc Bug description
-- pub Whether the bug report is to be made public
--
-- Returns:
-- br_id The bug report's identifier
-- bg_id The bug report's group
--
CREATE OR REPLACE FUNCTION bugs.post_admin_report( a_id INT , r_ttl TEXT , r_desc TEXT , pub BOOLEAN , OUT br_id BIGINT , OUT bg_id BIGINT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
sub_id BIGINT;
e_id BIGINT;
BEGIN
-- Create the report
SELECT INTO br_id , bg_id * FROM bugs.post_report( TRUE , a_id , r_ttl , r_desc );
SELECT INTO sub_id submitter_id FROM bugs.events WHERE event_id = br_id;
-- Mark the report as "OPEN"
INSERT INTO bugs.events ( group_id , submitter_id , e_type )
VALUES ( bg_id , sub_id , 'STATUS' )
RETURNING event_id INTO e_id;
INSERT INTO bugs.status_change_events ( event_id , status )
VALUES ( e_id , 'OPEN' );
-- Mark the report as visible if required
IF pub
THEN
INSERT INTO bugs.events ( group_id , submitter_id , e_type )
VALUES ( bg_id , sub_id , 'VISIBILITY' )
RETURNING event_id INTO e_id;
INSERT INTO bugs.visibility_events ( event_id , visible )
VALUES ( e_id , TRUE );
END IF;
-- Mark the report as read by the reporter
INSERT INTO bugs.admin_view_status ( group_id , admin_id )
VALUES ( bg_id , a_id );
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Posted bug report #' || br_id || ': ' || r_ttl );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION bugs.post_admin_report( INT , TEXT , TEXT , BOOLEAN ) TO :dbuser;
--
-- Posts a comment on an existing bug report
--
-- Parameters:
-- a_id Admin identifier
-- br_id Bug report identifier
-- c_txt Comment to post
-- pub Whether the comment should be made public or not
--
CREATE OR REPLACE FUNCTION bugs.post_admin_comment( a_id INT , br_id BIGINT , c_txt TEXT , pub BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
sub_id BIGINT;
grp_id BIGINT;
cmt_id BIGINT;
BEGIN
-- Get submitter and group
sub_id := bugs.goc_admin_submitter( a_id );
SELECT INTO grp_id group_id FROM bugs.br_groups WHERE bug_report_id = br_id;
-- If the message is public, notify users
IF pub
THEN
PERFORM bugs.update_notification( br_id , sub_id );
END IF;
-- Insert comment
INSERT INTO bugs.events ( group_id , submitter_id , e_type )
VALUES ( grp_id , sub_id , 'COMMENT' )
RETURNING event_id INTO cmt_id;
INSERT INTO bugs.comment_events ( event_id , comment , visible )
VALUES ( cmt_id , c_txt , pub );
-- Update view status
UPDATE bugs.admin_view_status SET last_view = now( )
WHERE admin_id = a_id AND group_id = grp_id;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION bugs.post_admin_comment( INT , BIGINT , TEXT , BOOLEAN ) TO :dbuser;
--
-- Reads a bug report
--
-- Parameters:
-- a_id Admin identifier
-- br_id Bug report to read
--
-- Returns:
-- The bug report as descibed by bugs.br_admin_view
--
CREATE OR REPLACE FUNCTION bugs.read_admin_report( a_id INT , br_id BIGINT )
RETURNS SETOF bugs.br_admin_view
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
rec bugs.br_admin_view;
BEGIN
SELECT INTO rec mv.* FROM bugs.br_admin_view mv
INNER JOIN bugs.br_groups bg USING ( group_id )
WHERE mv.administrator_id = a_id AND bg.bug_report_id = br_id;
IF FOUND
THEN
LOOP
UPDATE bugs.admin_view_status vs SET last_view = now( )
FROM bugs.br_groups bg
WHERE bg.bug_report_id = br_id AND vs.group_id = bg.group_id
AND vs.admin_id = a_id;
EXIT WHEN FOUND;
BEGIN
INSERT INTO bugs.admin_view_status ( group_id , admin_id )
SELECT group_id , a_id FROM bugs.br_groups
WHERE bug_report_id = br_id;
EXIT;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
END LOOP;
RETURN NEXT rec;
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION bugs.read_admin_report( INT , BIGINT ) TO :dbuser;
--
-- Make a comment visible
--
-- Parameters:
-- a_id Admin identifier
-- cmt_id Comment identifier
--
CREATE OR REPLACE FUNCTION bugs.show_comment( a_id INT , cmt_id BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
s_admin BOOLEAN;
s_name TEXT;
br_id BIGINT;
sub_id BIGINT;
c_text TEXT;
grp_id BIGINT;
evt_id BIGINT;
BEGIN
SELECT INTO s_admin , s_name , br_id , sub_id , c_text , grp_id
is_admin , name , bug_report_id , submitter_id , comment , group_id
FROM bugs.events e
INNER JOIN bugs.comment_events c USING ( event_id )
INNER JOIN bugs.submitters s USING ( submitter_id )
INNER JOIN bugs.br_first_report fr USING ( group_id )
WHERE event_id = cmt_id AND NOT visible
FOR UPDATE OF e , c , s;
IF FOUND
THEN
PERFORM bugs.update_notification( br_id , sub_id );
-- Delete old version
DELETE FROM bugs.comment_events WHERE event_id = cmt_id;
DELETE FROM bugs.events WHERE event_id = cmt_id;
-- Re-insert comment
INSERT INTO bugs.events ( group_id , submitter_id , e_type )
VALUES ( grp_id , sub_id , 'COMMENT' )
RETURNING event_id INTO evt_id;
INSERT INTO bugs.comment_events ( event_id , comment , visible )
VALUES ( evt_id , c_text , TRUE );
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Validated bug comment #' || cmt_id
|| ' posted by ' || ( CASE WHEN s_admin THEN 'administrator' ELSE 'empire' END )
|| ' ' || s_name );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION bugs.show_comment( INT , BIGINT ) TO :dbuser;
--
-- Deletes a comment
--
-- Parameters:
-- a_id Admin identifier
-- cmt_id Comment identifier
--
CREATE OR REPLACE FUNCTION bugs.delete_comment( a_id INT , cmt_id BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
s_admin BOOLEAN;
s_name TEXT;
BEGIN
SELECT INTO s_admin , s_name is_admin , name
FROM bugs.events
INNER JOIN bugs.comment_events USING ( event_id )
INNER JOIN bugs.submitters USING ( submitter_id )
WHERE event_id = cmt_id AND NOT visible
FOR UPDATE;
IF FOUND
THEN
DELETE FROM bugs.comment_events WHERE event_id = cmt_id;
DELETE FROM bugs.events WHERE event_id = cmt_id;
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Deleted bug comment #' || cmt_id
|| ' posted by ' || ( CASE WHEN s_admin THEN 'administrator' ELSE 'empire' END )
|| ' ' || s_name );
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION bugs.delete_comment( INT , BIGINT ) TO :dbuser;
--
-- Validates a bug report
--
-- Parameters:
-- a_id Admin identifier
-- br_id Report identifier
-- n_stat New status
-- is_pub Whether the report is to be made public
-- g_creds Credits to grand (0: none, 1: small amount, 2: medium, 3: lots)
-- keep_snap Whether the snapshot of the empire should be kept
--
CREATE OR REPLACE FUNCTION bugs.validate_report( a_id INT , br_id BIGINT , n_stat bug_status_type , is_pub BOOLEAN , g_creds INT , keep_snap BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
grp_id BIGINT;
evt_id BIGINT;
sub_id BIGINT;
u_id INT;
rgc INT := 0;
BEGIN
-- Find and lock the record
SELECT INTO grp_id evt.group_id
FROM bugs.initial_report_events ire
INNER JOIN bugs.events evt ON ire.event_id = evt.event_id
INNER JOIN bugs.groups bg ON bg.group_id = evt.group_id
LEFT OUTER JOIN bugs.events oe ON oe.group_id = evt.group_id AND oe.e_type = 'STATUS'
WHERE oe.group_id IS NULL AND ire.event_id = br_id
FOR UPDATE OF ire , evt , bg;
IF NOT FOUND
THEN
RETURN;
END IF;
-- Send update notifications
sub_id := bugs.goc_admin_submitter( a_id );
PERFORM bugs.update_notification( br_id , sub_id );
-- Set new status
INSERT INTO bugs.events ( group_id , submitter_id , e_type )
VALUES ( grp_id , sub_id , 'STATUS' )
RETURNING event_id INTO evt_id;
INSERT INTO bugs.status_change_events ( event_id , status )
VALUES ( evt_id , n_stat );
-- Set visibility
IF is_pub
THEN
INSERT INTO bugs.events( group_id , submitter_id , e_type )
VALUES ( grp_id , sub_id , 'VISIBILITY' )
RETURNING event_id INTO evt_id;
INSERT INTO bugs.visibility_events ( event_id , visible )
VALUES ( evt_id , is_pub );
END IF;
-- Grant credits, if requested and possible
IF g_creds > 0
THEN
SELECT INTO u_id account_id
FROM bugs.events
INNER JOIN bugs.user_submitters USING (submitter_id)
WHERE event_id = br_id;
IF FOUND
THEN
rgc := floor( CASE g_creds
WHEN 1 THEN sys.get_constant( 'bugtracker.lowCredits')
WHEN 2 THEN sys.get_constant( 'bugtracker.mediumCredits')
ELSE sys.get_constant( 'bugtracker.highCredits')
END );
UPDATE users.credentials
SET credits = credits + g_creds
WHERE address_id = u_id;
END IF;
END IF;
-- Remove snapshot data
IF NOT keep_snap
THEN
DELETE FROM bugs.account_status_data WHERE event_id = br_id;
END IF;
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Validation of bug report #' || br_id
|| ': status set to ' || n_stat || ', visibility ' || ( CASE WHEN is_pub THEN 'public' ELSE 'hidden' END )
|| ', ' || rgc || ' credit(s) granted, snapshot ' || (CASE WHEN keep_snap THEN 'kept' ELSE 'deleted' END ) || '.' );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION bugs.validate_report( INT , BIGINT , bug_status_type , BOOLEAN , INT , BOOLEAN ) TO :dbuser;
--
-- Sets a bug report's status
--
-- Parameters:
-- a_id Admin identifier
-- br_id Report identifier
-- n_stat New status
--
CREATE OR REPLACE FUNCTION bugs.set_report_status( a_id INT , br_id BIGINT , n_stat bug_status_type )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
grp_id BIGINT;
evt_id BIGINT;
sub_id BIGINT;
BEGIN
-- Find and lock the record
SELECT INTO grp_id evt.group_id
FROM bugs.initial_report_events ire
INNER JOIN bugs.events evt ON ire.event_id = evt.event_id
INNER JOIN bugs.groups bg ON bg.group_id = evt.group_id
WHERE ire.event_id = br_id
FOR UPDATE OF ire , evt , bg;
IF NOT FOUND
THEN
RETURN;
END IF;
-- Do not add status change events if the status is already the same
PERFORM status FROM bugs.br_main_view
WHERE group_id = grp_id AND status <> n_stat::TEXT;
IF NOT FOUND
THEN
RETURN;
END IF;
-- Set new status
sub_id := bugs.goc_admin_submitter( a_id );
PERFORM bugs.update_notification( br_id , sub_id );
INSERT INTO bugs.events ( group_id , submitter_id , e_type )
VALUES ( grp_id , sub_id , 'STATUS' )
RETURNING event_id INTO evt_id;
INSERT INTO bugs.status_change_events ( event_id , status )
VALUES ( evt_id , n_stat );
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Set status of bug report #' || br_id || ' to ' || n_stat );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION bugs.set_report_status( INT , BIGINT , bug_status_type ) TO :dbuser;
--
-- Changes a bug report's visibility
--
-- Parameters:
-- a_id Admin identifier
-- br_id Report identifier
--
CREATE OR REPLACE FUNCTION bugs.toggle_report_visibility( a_id INT , br_id BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
grp_id BIGINT;
evt_id BIGINT;
sub_id BIGINT;
c_vis BOOLEAN;
BEGIN
-- Find and lock the record
SELECT INTO grp_id evt.group_id
FROM bugs.initial_report_events ire
INNER JOIN bugs.events evt ON ire.event_id = evt.event_id
INNER JOIN bugs.groups bg ON bg.group_id = evt.group_id
WHERE ire.event_id = br_id
FOR UPDATE OF ire , evt , bg;
IF NOT FOUND
THEN
RETURN;
END IF;
-- Get the report's current visibility
SELECT INTO c_vis visible FROM bugs.br_main_view WHERE group_id = grp_id;
-- Set new visibility
sub_id := bugs.goc_admin_submitter( a_id );
PERFORM bugs.update_notification( br_id , sub_id );
INSERT INTO bugs.events ( group_id , submitter_id , e_type )
VALUES ( grp_id , sub_id , 'VISIBILITY' )
RETURNING event_id INTO evt_id;
INSERT INTO bugs.visibility_events ( event_id , visible )
VALUES ( evt_id , NOT c_vis );
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Bug report #' || br_id || ' is now '
||( CASE WHEN c_vis THEN 'hidden' ELSE 'public' END ) );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION bugs.toggle_report_visibility( INT , BIGINT ) TO :dbuser;
--
-- Merges two bug reports
--
-- Parameters:
-- a_id Administrator identifier
-- br1_id First bug report
-- br2_id Second bug report
--
-- Returns:
-- err_code Error code:
-- 0 no error
-- 1 bug report not found
-- 2 bug reports already merged
-- 3 incorrect status (both reports should be OPEN)
--
CREATE OR REPLACE FUNCTION bugs.merge_reports( a_id INT , br1_id BIGINT , br2_id BIGINT , OUT err_code INT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
grp1_id BIGINT;
grp2_id BIGINT;
grp1_s TEXT;
grp2_s TEXT;
evt_id BIGINT;
sub_id BIGINT;
BEGIN
-- Get group identifiers and statuses
SELECT INTO grp1_id , grp1_s g.group_id , sv.status
FROM bugs.initial_report_events ire
INNER JOIN bugs.events evt USING (event_id)
INNER JOIN bugs.groups g USING ( group_id )
INNER JOIN bugs.br_status sv USING ( group_id )
WHERE ire.event_id = br1_id
FOR UPDATE OF ire , evt , g;
IF NOT FOUND
THEN
err_code := 1;
RETURN;
END IF;
SELECT INTO grp2_id , grp2_s g.group_id , sv.status
FROM bugs.initial_report_events ire
INNER JOIN bugs.events evt USING (event_id)
INNER JOIN bugs.groups g USING ( group_id )
INNER JOIN bugs.br_status sv USING ( group_id )
WHERE ire.event_id = br2_id
FOR UPDATE OF ire , evt , g;
IF NOT FOUND
THEN
err_code := 1;
RETURN;
ELSEIF grp1_id = grp2_id
THEN
err_code := 2;
RETURN;
ELSEIF grp1_s <> 'OPEN' OR grp2_s <> 'OPEN'
THEN
err_code := 3;
RETURN;
END IF;
-- Send update notification
sub_id := bugs.goc_admin_submitter( a_id );
PERFORM bugs.update_notification( br1_id , br2_id , sub_id );
-- Move events
UPDATE bugs.events SET group_id = grp2_id
WHERE group_id = grp1_id;
-- Prepare update of user view status
CREATE TEMPORARY TABLE vs_move(
user_id INT ,
last_view TIMESTAMP WITHOUT TIME ZONE
) ON COMMIT DROP;
INSERT INTO vs_move
SELECT user_id , max( last_view ) FROM bugs.user_view_status
WHERE group_id = grp1_id OR group_id = grp2_id
GROUP BY user_id;
-- Add merge event
INSERT INTO bugs.events ( group_id , submitter_id , e_type )
VALUES ( grp2_id , sub_id , 'MERGE' )
RETURNING event_id INTO evt_id;
INSERT INTO bugs.merge_events ( event_id , initial_post_id )
VALUES ( evt_id , br1_id );
-- Update user view status, delete old group
DELETE FROM bugs.user_view_status WHERE group_id = grp1_id OR group_id = grp2_id;
INSERT INTO bugs.user_view_status( group_id , user_id , last_view )
SELECT grp2_id , user_id , last_view FROM vs_move;
DELETE FROM bugs.groups WHERE group_id = grp1_id;
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Merged bug report #' || br1_id
|| ' into report #' || br2_id );
err_code := 0;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION bugs.merge_reports( INT , BIGINT , BIGINT ) TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- VIEWS USED TO GENERATE XML DUMPS --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
CREATE VIEW bugs.dump_main_view
AS SELECT ss.current_tick , ss.next_tick ,
u.id AS account_id , u.address AS account_address , u.game_credits ,
u.status AS account_status , u.language AS account_language ,
e.name_id AS empire_id , u.current_empire AS empire_name , e.cash AS cash ,
a.id AS alliance_id , a.tag AS alliance_tag , am.is_pending AS alliance_pending
FROM emp.empires e
INNER JOIN admin.users_list u ON u.current_empire_id = e.name_id
INNER JOIN sys.status ss ON TRUE
LEFT OUTER JOIN emp.alliance_members am ON am.empire_id = e.name_id
LEFT OUTER JOIN emp.alliances a ON a.id = am.alliance_id;
GRANT SELECT ON bugs.dump_main_view TO :dbuser;
CREATE VIEW bugs.dump_research_view
AS SELECT r.empire_id , ns.name , r.accumulated , r.priority
FROM emp.research r
INNER JOIN defs.strings ns ON ns.id = r.technology_id;
GRANT SELECT ON bugs.dump_research_view TO :dbuser;
CREATE VIEW bugs.dump_technologies_view
AS SELECT et.empire_id , ns.name , et.implemented
FROM emp.researched_technologies et
INNER JOIN defs.strings ns ON ns.id = et.technology_id;
GRANT SELECT ON bugs.dump_technologies_view TO :dbuser;
CREATE VIEW bugs.dump_planets_view
AS SELECT ep.empire_id , ep.planet_id , p.population ,
ph.current / p.population AS current_happiness , ph.target AS target_happiness ,
cq.money AS civ_money , cq.work AS civ_work ,
mq.money AS mil_money , mq.work AS mil_work
FROM emp.planets ep
INNER JOIN verse.planets p ON p.name_id = ep.planet_id
INNER JOIN verse.planet_happiness ph ON ph.planet_id = p.name_id
INNER JOIN verse.bld_queues cq ON cq.planet_id = p.name_id
INNER JOIN verse.mil_queues mq ON mq.planet_id = p.name_id
ORDER BY ep.planet_id;
GRANT SELECT ON bugs.dump_planets_view TO :dbuser;
CREATE VIEW bugs.dump_queues_view
AS SELECT ep.empire_id , ep.planet_id , FALSE AS military , q.queue_order ,
q.building_id AS item_id , qin.name AS item_name ,
q.destroy , q.amount
FROM emp.planets ep
INNER JOIN verse.bld_items q ON q.queue_id = ep.planet_id
INNER JOIN defs.strings qin ON qin.id = q.building_id
UNION ALL SELECT ep.empire_id , ep.planet_id , TRUE AS military , q.queue_order ,
q.ship_id AS item_id , qin.name AS item_name , FALSE AS destroy , q.amount
FROM emp.planets ep
INNER JOIN verse.mil_items q ON q.queue_id = ep.planet_id
INNER JOIN defs.strings qin ON qin.id = q.ship_id;
GRANT SELECT ON bugs.dump_queues_view TO :dbuser;
CREATE VIEW bugs.dump_buildings_view
AS SELECT ep.empire_id , ep.planet_id , b.building_id , bn.name AS building_name ,
b.amount , b.damage
FROM emp.planets ep
INNER JOIN verse.planet_buildings b USING( planet_id )
INNER JOIN defs.strings bn ON bn.id = b.building_id
WHERE b.amount > 0
ORDER BY building_id;
GRANT SELECT ON bugs.dump_buildings_view TO :dbuser;
CREATE VIEW bugs.dump_fleets_view
AS SELECT f.owner_id AS empire_id , f.id AS fleet_id , f.name AS fleet_name ,
f.status , f.attacking , f.location_id , fln.name AS location_name ,
fm.source_id , fsn.name AS source_name , fm.time_left , fm.state_time_left ,
fmis.ref_point_id , rpn.name AS ref_point_name , fmis.outwards , fmis.past_ref_point ,
fmos.start_x , fmos.start_y
FROM fleets.fleets f
INNER JOIN naming.map_names fln ON fln.id = f.location_id
LEFT OUTER JOIN fleets.movements fm ON fm.fleet_id = f.id
LEFT OUTER JOIN naming.map_names fsn ON fsn.id = fm.source_id
LEFT OUTER JOIN fleets.ms_system fmis ON fmis.movement_id = f.id
LEFT OUTER JOIN naming.map_names rpn ON rpn.id = fmis.ref_point_id
LEFT OUTER JOIN fleets.ms_space fmos ON fmos.movement_id = f.id
ORDER BY f.location_id , f.id;
GRANT SELECT ON bugs.dump_fleets_view TO :dbuser;
CREATE VIEW bugs.dump_ships_view
AS SELECT f.owner_id AS empire_id , s.fleet_id , s.ship_id , sn.name AS ship_name ,
s.amount , s.damage
FROM fleets.fleets f
INNER JOIN fleets.ships s ON s.fleet_id = f.id
INNER JOIN defs.strings sn ON sn.id = s.ship_id
ORDER BY s.ship_id;
GRANT SELECT ON bugs.dump_ships_view TO :dbuser;