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/180-messages-functions.sql

1277 lines
36 KiB
PL/PgSQL

-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- Functions and views to handle messages
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- INTERNAL FUNCTIONS THAT HANDLE SENDING MESSAGES --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Creates or retrieves a sender record
--
-- Parameters:
-- r_type Sender type
-- r_id Sender identifier
--
CREATE OR REPLACE FUNCTION msgs.goc_sender( s_type sender_type , s_id INT )
RETURNS BIGINT
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
snd_id BIGINT;
s_name TEXT;
BEGIN
LOOP
SELECT INTO snd_id id FROM msgs.senders
WHERE ( CASE s_type
WHEN 'EMP' THEN
empire_id = s_id
ELSE
admin_id = s_id
END );
EXIT WHEN FOUND;
BEGIN
IF s_type = 'EMP'
THEN
SELECT INTO s_name name FROM naming.empire_names
WHERE id = s_id;
INSERT INTO msgs.senders( sender_type , name , empire_id )
VALUES ( s_type , s_name , s_id )
RETURNING id INTO snd_id;
ELSE
SELECT INTO s_name appear_as FROM admin.administrators
WHERE id = s_id;
INSERT INTO msgs.senders( sender_type , name , admin_id )
VALUES ( s_type , s_name , s_id )
RETURNING id INTO snd_id;
END IF;
EXIT;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
END LOOP;
RETURN snd_id;
END;
$$ LANGUAGE plpgsql;
--
-- Creates or retrieves a receiver record
--
-- Parameters:
-- r_type Receiver type
-- r_id Receiver identifier
--
CREATE OR REPLACE FUNCTION msgs.goc_receiver( r_type receiver_type , r_id INT )
RETURNS BIGINT
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
rec_id BIGINT;
r_name TEXT;
BEGIN
LOOP
SELECT INTO rec_id id FROM msgs.receivers
WHERE ( CASE r_type
WHEN 'EMP' THEN
empire_id = r_id
WHEN 'ADM' THEN
admin_id = r_id
ELSE
alliance_id = r_id
END );
EXIT WHEN FOUND;
BEGIN
IF r_type = 'EMP'
THEN
SELECT INTO r_name name FROM naming.empire_names
WHERE id = r_id;
INSERT INTO msgs.receivers( receiver_type , name , empire_id )
VALUES ( r_type , r_name , r_id )
RETURNING id INTO rec_id;
ELSEIF r_type = 'ADM'
THEN
SELECT INTO r_name appear_as FROM admin.administrators
WHERE id = r_id;
INSERT INTO msgs.receivers( receiver_type , name , admin_id )
VALUES ( r_type , r_name , r_id )
RETURNING id INTO rec_id;
ELSE
SELECT INTO r_name tag FROM emp.alliances
WHERE id = r_id;
INSERT INTO msgs.receivers( receiver_type , name , alliance_id )
VALUES ( r_type , r_name , r_id )
RETURNING id INTO rec_id;
END IF;
EXIT;
EXCEPTION
WHEN unique_violation THEN
-- Do nothing
END;
END LOOP;
RETURN rec_id;
END;
$$ LANGUAGE plpgsql;
--
-- Stores a message in an empire's message box
--
-- Parameters:
-- e_id Empire identifier
-- m_id Message identifier
-- received Whether the message is to be delivered in the inbox or in the outbox
--
CREATE OR REPLACE FUNCTION msgs.deliver_to_empire( e_id INT , m_id BIGINT , received BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
INSERT INTO msgs.empire_delivery ( empire_id , message_id , in_inbox , status , emailed , recaped )
VALUES ( $1 , $2 , $3 , ( CASE WHEN $3 THEN 'UNREAD' ELSE 'READ' END )::message_status , NOT $3 , NOT $3 );
$$ LANGUAGE SQL;
--
-- Stores a message in an administrator's message box
--
-- Parameters:
-- a_id Administrator identifier
-- m_id Message identifier
-- received Whether the message is to be delivered in the inbox or in the outbox
--
CREATE OR REPLACE FUNCTION msgs.deliver_to_admin( a_id INT , m_id BIGINT , received BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
INSERT INTO msgs.admin_delivery ( admin_id , message_id , in_inbox , status , emailed )
VALUES ( $1 , $2 , $3 , ( CASE WHEN $3 THEN 'UNREAD' ELSE 'READ' END )::message_status , NOT $3 );
$$ LANGUAGE SQL;
--
-- Deliver new internal messages to an empire
--
-- Parameters:
-- e_id Empire identifier
--
CREATE OR REPLACE FUNCTION msgs.deliver_internal( e_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
rec_id BIGINT;
evt_id BIGINT;
msg_id BIGINT;
max_id BIGINT;
BEGIN
rec_id := msgs.goc_receiver( 'EMP'::receiver_type , e_id );
max_id := 0;
FOR evt_id IN SELECT event_id FROM events.events
WHERE empire_id = e_id AND status = 'READY'
FOR UPDATE
LOOP
INSERT INTO msgs.messages ( receiver_id , event_content_id )
VALUES ( rec_id , evt_id )
RETURNING id INTO msg_id;
PERFORM msgs.deliver_to_empire( e_id , msg_id , TRUE );
CONTINUE WHEN max_id > evt_id;
max_id := evt_id;
END LOOP;
UPDATE events.events SET status = 'SENT'
WHERE empire_id = e_id AND status = 'READY' AND event_id <= max_id;
END;
$$ LANGUAGE plpgsql;
--
-- Deliver pending internal messages
--
CREATE OR REPLACE FUNCTION msgs.deliver_internal( )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
e_id INT;
BEGIN
FOR e_id IN SELECT DISTINCT empire_id FROM events.events
WHERE status = 'READY'
LOOP
PERFORM msgs.deliver_internal( e_id );
END LOOP;
END;
$$ LANGUAGE plpgsql;
--
-- Sends a message from an empire to an empire
--
CREATE OR REPLACE FUNCTION msgs.deliver_private( se_id INT , de_id INT , ttl_txt TEXT , cnt_txt TEXT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
snd_id BIGINT;
rec_id BIGINT;
tm_id BIGINT;
msg_id BIGINT;
BEGIN
snd_id := msgs.goc_sender( 'EMP'::sender_type , se_id );
rec_id := msgs.goc_receiver( 'EMP'::receiver_type , de_id );
INSERT INTO msgs.text_messages ( tick , title , contents )
VALUES ( sys.get_tick() - 1 , ttl_txt , cnt_txt )
RETURNING id INTO tm_id;
INSERT INTO msgs.messages ( sender_id , receiver_id , text_content_id )
VALUES ( snd_id , rec_id , tm_id )
RETURNING id INTO msg_id;
PERFORM msgs.deliver_to_empire( de_id , msg_id , TRUE );
PERFORM msgs.deliver_to_empire( se_id , msg_id , FALSE );
END;
$$ LANGUAGE plpgsql;
--
-- Sends a message from an empire to an alliance
--
CREATE OR REPLACE FUNCTION msgs.deliver_alliance( se_id INT , da_id INT , ttl_txt TEXT , cnt_txt TEXT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
emp_id INT;
snd_id BIGINT;
rec_id BIGINT;
tm_id BIGINT;
msg_id BIGINT;
BEGIN
snd_id := msgs.goc_sender( 'EMP'::sender_type , se_id );
rec_id := msgs.goc_receiver( 'ALL'::receiver_type , da_id );
INSERT INTO msgs.text_messages ( tick , title , contents )
VALUES ( sys.get_tick() - 1 , ttl_txt , cnt_txt )
RETURNING id INTO tm_id;
INSERT INTO msgs.messages ( sender_id , receiver_id , text_content_id )
VALUES ( snd_id , rec_id , tm_id )
RETURNING id INTO msg_id;
SELECT INTO emp_id alliance_id FROM emp.alliance_members WHERE empire_id = se_id AND NOT is_pending;
IF FOUND AND emp_id = da_id
THEN
FOR emp_id IN SELECT empire_id FROM emp.alliance_members
WHERE empire_id <> se_id AND NOT is_pending
AND alliance_id = da_id
LOOP
PERFORM msgs.deliver_to_empire( emp_id , msg_id , TRUE );
END LOOP;
ELSE
SELECT INTO emp_id leader_id FROM emp.alliances WHERE id = da_id;
PERFORM msgs.deliver_to_empire( emp_id , msg_id , TRUE );
END IF;
PERFORM msgs.deliver_to_empire( se_id , msg_id , FALSE );
END;
$$ LANGUAGE plpgsql;
--
-- Sends a message from an empire to an administrator
--
CREATE OR REPLACE FUNCTION msgs.deliver_toadmin( se_id INT , da_id INT , ttl_txt TEXT , cnt_txt TEXT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
snd_id BIGINT;
rec_id BIGINT;
tm_id BIGINT;
msg_id BIGINT;
BEGIN
snd_id := msgs.goc_sender( 'EMP'::sender_type , se_id );
rec_id := msgs.goc_receiver( 'ADM'::receiver_type , da_id );
INSERT INTO msgs.text_messages ( tick , title , contents )
VALUES ( sys.get_tick() - 1 , ttl_txt , cnt_txt )
RETURNING id INTO tm_id;
INSERT INTO msgs.messages ( sender_id , receiver_id , text_content_id )
VALUES ( snd_id , rec_id , tm_id )
RETURNING id INTO msg_id;
PERFORM msgs.deliver_to_admin( da_id , msg_id , TRUE );
PERFORM msgs.deliver_to_empire( se_id , msg_id , FALSE );
END;
$$ LANGUAGE plpgsql;
--
-- Sends a message from an administrator to an empire
--
CREATE OR REPLACE FUNCTION msgs.deliver_admin_toempire( sa_id INT , de_id INT , ttl_txt TEXT , cnt_txt TEXT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
snd_id BIGINT;
rec_id BIGINT;
tm_id BIGINT;
msg_id BIGINT;
BEGIN
snd_id := msgs.goc_sender( 'ADM'::sender_type , sa_id );
rec_id := msgs.goc_receiver( 'EMP'::receiver_type , de_id );
INSERT INTO msgs.text_messages ( tick , title , contents )
VALUES ( sys.get_tick() - 1 , ttl_txt , cnt_txt )
RETURNING id INTO tm_id;
INSERT INTO msgs.messages ( sender_id , receiver_id , text_content_id )
VALUES ( snd_id , rec_id , tm_id )
RETURNING id INTO msg_id;
PERFORM msgs.deliver_to_empire( de_id , msg_id , TRUE );
PERFORM msgs.deliver_to_admin( sa_id , msg_id , FALSE );
END;
$$ LANGUAGE plpgsql;
--
-- Sends a message from an administrator to an administrator
--
CREATE OR REPLACE FUNCTION msgs.deliver_admin_toadmin( sa_id INT , da_id INT , ttl_txt TEXT , cnt_txt TEXT )
RETURNS VOID
STRICT VOLATILE
SECURITY INVOKER
AS $$
DECLARE
snd_id BIGINT;
rec_id BIGINT;
tm_id BIGINT;
msg_id BIGINT;
BEGIN
snd_id := msgs.goc_sender( 'ADM'::sender_type , sa_id );
rec_id := msgs.goc_receiver( 'ADM'::receiver_type , da_id );
INSERT INTO msgs.text_messages ( tick , title , contents )
VALUES ( sys.get_tick() - 1 , ttl_txt , cnt_txt )
RETURNING id INTO tm_id;
INSERT INTO msgs.messages ( sender_id , receiver_id , text_content_id )
VALUES ( snd_id , rec_id , tm_id )
RETURNING id INTO msg_id;
PERFORM msgs.deliver_to_admin( da_id , msg_id , TRUE );
PERFORM msgs.deliver_to_admin( sa_id , msg_id , FALSE );
END;
$$ LANGUAGE plpgsql;
--
-- Sends a message from an administrator to all empires
--
CREATE OR REPLACE FUNCTION msgs.deliver_admin_spam( sa_id INT , ttl_txt TEXT , cnt_txt TEXT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
de_id INT;
snd_id BIGINT;
rec_id BIGINT;
tm_id BIGINT;
msg_id BIGINT;
BEGIN
PERFORM admin.write_log( sa_id , 'INFO'::log_level , 'Sending spam "' || ttl_txt || '"' );
snd_id := msgs.goc_sender( 'ADM'::sender_type , sa_id );
INSERT INTO msgs.text_messages ( tick , title , contents )
VALUES ( sys.get_tick() - 1 , ttl_txt , cnt_txt )
RETURNING id INTO tm_id;
FOR de_id IN SELECT name_id FROM emp.empires
LOOP
rec_id := msgs.goc_receiver( 'EMP'::receiver_type , de_id );
INSERT INTO msgs.messages ( sender_id , receiver_id , text_content_id )
VALUES ( snd_id , rec_id , tm_id )
RETURNING id INTO msg_id;
PERFORM msgs.deliver_to_empire( de_id , msg_id , TRUE );
END LOOP;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION msgs.deliver_admin_spam( INT , TEXT , TEXT ) TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- EMPIRE MESSAGE BOX AND MESSAGE SENDER --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Empire inbox
--
CREATE VIEW msgs.empire_inbox
AS SELECT db.id , db.empire_id , ( db.status = 'READ' ) AS read ,
( CASE
WHEN s.id IS NULL
THEN 'INT'
ELSE s.sender_type::TEXT
END ) AS sender_type ,
( CASE
WHEN s.id IS NULL
THEN NULL::INT
WHEN s.sender_type = 'EMP'
THEN s.empire_id
ELSE s.admin_id
END ) AS sender_id ,
s.name AS sender_name , r.receiver_type ,
( CASE
WHEN r.receiver_type = 'EMP'
THEN r.empire_id
WHEN r.receiver_type = 'ALL'
THEN r.alliance_id
ELSE r.admin_id
END ) AS receiver_id , r.name AS receiver_name ,
( tm.id IS NULL ) AS internal_message ,
( CASE
WHEN tm.id IS NULL
THEN evt.event_id
ELSE tm.id
END ) AS content_id ,
( CASE
WHEN tm.id IS NULL
THEN evt.real_time
ELSE tm.t
END ) AS r_time
FROM msgs.empire_delivery db
INNER JOIN msgs.messages m ON m.id = db.message_id
INNER JOIN msgs.receivers r ON r.id = m.receiver_id
LEFT OUTER JOIN msgs.senders s ON m.sender_id = s.id
LEFT OUTER JOIN events.events evt ON evt.event_id = m.event_content_id
LEFT OUTER JOIN msgs.text_messages tm ON tm.id = m.text_content_id
WHERE db.in_inbox AND db.status <> 'DELETED'
ORDER BY ( CASE
WHEN tm.id IS NULL
THEN evt.real_time
ELSE tm.t
END ) DESC;
GRANT SELECT ON msgs.empire_inbox TO :dbuser;
--
-- Empire outbox
--
CREATE VIEW msgs.empire_outbox
AS SELECT db.id , db.empire_id , TRUE AS read ,
'EMP'::TEXT AS sender_type , db.empire_id AS sender_id , en.name AS sender_name ,
r.receiver_type ,
( CASE
WHEN r.receiver_type = 'EMP'
THEN r.empire_id
WHEN r.receiver_type = 'ALL'
THEN r.alliance_id
ELSE r.admin_id
END ) AS receiver_id , r.name AS receiver_name ,
FALSE AS internal_message ,
tm.id AS content_id , tm.t AS r_time
FROM msgs.empire_delivery db
INNER JOIN msgs.messages m ON m.id = db.message_id
INNER JOIN msgs.receivers r ON r.id = m.receiver_id
INNER JOIN msgs.text_messages tm ON tm.id = m.text_content_id
INNER JOIN naming.empire_names en ON en.id = db.empire_id
WHERE NOT db.in_inbox AND db.status <> 'DELETED'
ORDER BY tm.t DESC;
GRANT SELECT ON msgs.empire_outbox TO :dbuser;
--
-- Sends a message from an empire to a target
--
-- Parameters:
-- e_id Empire sending a message
-- to_type Type of message target (empire, alliance or admin)
-- to_name Name of the message target
-- ttl_txt Title of the message
-- cnt_txt Contents of the message
-- do_send Whether the message should actually be sent (used to verify target existence)
--
-- Returns:
-- err_code Error code:
-- 0 success
-- 1 unknown target
-- 2 too soon
--
CREATE OR REPLACE FUNCTION msgs.send_message( e_id INT , to_type receiver_type , to_name TEXT , ttl_txt TEXT ,
cnt_txt TEXT , do_send BOOLEAN , OUT err_code INT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
tg_id INT;
s_meth TEXT;
BEGIN
-- Find target and sending method
IF to_type = 'ADM'
THEN
s_meth := 'toadmin';
SELECT INTO tg_id id FROM admin.administrators
WHERE lower( appear_as ) = lower( to_name );
ELSEIF to_type = 'EMP'
THEN
s_meth := 'private';
SELECT INTO tg_id id FROM naming.empire_names n
INNER JOIN emp.empires e ON e.name_id = n.id
WHERE lower( name ) = lower( to_name );
ELSE
s_meth := 'alliance';
SELECT INTO tg_id id FROM emp.alliances
WHERE lower( tag ) = lower( to_name );
END IF;
IF NOT FOUND
THEN
err_code := 1;
RETURN;
END IF;
-- Check last message sent by this empire
PERFORM r_time FROM msgs.empire_outbox WHERE empire_id = e_id AND r_time > now() - '20s'::INTERVAL;
IF FOUND
THEN
err_code := 2;
RETURN;
END IF;
-- Send message (or not)
IF do_send
THEN
PERFORM sys.write_log( 'Messages' , 'DEBUG'::log_level , 'Delivering message from empire #' || e_id
|| ' using method ' || s_meth || ' with target identifier ' || tg_id || ' (title text null? '
|| ( ttl_txt IS NULL ) || ' ; content text null? ' || (cnt_txt IS NULL) || ')' );
EXECUTE 'SELECT msgs.deliver_' || s_meth || '( $1 , $2 , $3 , $4 )'
USING e_id , tg_id , ttl_txt , cnt_txt;
ELSE
PERFORM sys.write_log( 'Messages' , 'DEBUG'::log_level , 'Simulated message delivery from empire #' || e_id
|| ' using method ' || s_meth || ' with target identifier ' || tg_id || ' (title text null? '
|| ( ttl_txt IS NULL ) || ' ; content text null? ' || (cnt_txt IS NULL) || ')' );
END IF;
err_code := 0;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION msgs.send_message( INT , receiver_type , TEXT , TEXT , TEXT , BOOLEAN ) TO :dbuser;
--
-- Marks specific messages as read in an empire's inbox
--
-- Parameters:
-- e_id Empire identifier
-- m_ids Message identifiers
--
CREATE OR REPLACE FUNCTION msgs.empire_mark_read( e_id INT , m_ids BIGINT[] )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
UPDATE msgs.empire_delivery
SET status = 'READ'
WHERE empire_id = $1 AND status = 'UNREAD' AND id = ANY( $2 ) AND in_inbox
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION msgs.empire_mark_read( INT , BIGINT[] ) TO :dbuser;
--
-- Marks all messages as read in an empire's inbox
--
-- Parameters:
-- e_id Empire identifier
-- m_ids Message identifiers
--
CREATE OR REPLACE FUNCTION msgs.empire_mark_read( e_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
UPDATE msgs.empire_delivery
SET status = 'READ'
WHERE empire_id = $1 AND status = 'UNREAD' AND in_inbox
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION msgs.empire_mark_read( INT ) TO :dbuser;
--
-- Marks specific messages as unread in an empire's inbox
--
-- Parameters:
-- e_id Empire identifier
-- m_ids Message identifiers
--
CREATE OR REPLACE FUNCTION msgs.empire_mark_unread( e_id INT , m_ids BIGINT[] )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
UPDATE msgs.empire_delivery
SET status = 'UNREAD'
WHERE empire_id = $1 AND status = 'READ' AND id = ANY( $2 ) AND in_inbox
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION msgs.empire_mark_unread( INT , BIGINT[] ) TO :dbuser;
--
-- Marks all messages as unread in an empire's inbox
--
-- Parameters:
-- e_id Empire identifier
-- m_ids Message identifiers
--
CREATE OR REPLACE FUNCTION msgs.empire_mark_unread( e_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
UPDATE msgs.empire_delivery
SET status = 'UNREAD'
WHERE empire_id = $1 AND status = 'READ' AND in_inbox
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION msgs.empire_mark_unread( INT ) TO :dbuser;
--
-- Marks specific messages as deleted in an empire's inbox or outbox
--
-- Parameters:
-- e_id Empire identifier
-- inbox Whether the affected messages are in the empire's inbox or in its outbox
-- m_ids Message identifiers
--
CREATE OR REPLACE FUNCTION msgs.empire_delete( e_id INT , inbox BOOLEAN , m_ids BIGINT[] )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
UPDATE msgs.empire_delivery
SET status = 'DELETED'
WHERE empire_id = $1 AND status <> 'DELETED' AND id = ANY( $3 ) AND in_inbox = $2
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION msgs.empire_delete( INT , BOOLEAN , BIGINT[] ) TO :dbuser;
--
-- Marks all messages as deleted in an empire's inbox or outbox
--
-- Parameters:
-- e_id Empire identifier
-- inbox Whether the affected messages are in the empire's inbox or in its outbox
-- m_ids Message identifiers
--
CREATE OR REPLACE FUNCTION msgs.empire_delete( e_id INT , inbox BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
UPDATE msgs.empire_delivery
SET status = 'DELETED'
WHERE empire_id = $1 AND status <> 'DELETED' AND in_inbox = $2
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION msgs.empire_delete( INT , BOOLEAN ) TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- ADMINISTRATOR MESSAGE BOX AND MESSAGE SENDER --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Admin inbox
--
CREATE VIEW msgs.admin_inbox
AS SELECT db.id , db.admin_id , ( db.status = 'READ' ) AS read ,
s.sender_type::TEXT AS sender_type ,
( CASE
WHEN s.sender_type = 'EMP'
THEN s.empire_id
ELSE s.admin_id
END ) AS sender_id ,
s.name AS sender_name , r.receiver_type ,
( CASE
WHEN r.receiver_type = 'EMP'
THEN r.empire_id
ELSE r.admin_id
END ) AS receiver_id , r.name AS receiver_name ,
FALSE AS internal_message ,
tm.id AS content_id ,
tm.t AS r_time
FROM msgs.admin_delivery db
INNER JOIN msgs.messages m ON m.id = db.message_id
INNER JOIN msgs.receivers r ON r.id = m.receiver_id
INNER JOIN msgs.senders s ON m.sender_id = s.id
INNER JOIN msgs.text_messages tm ON tm.id = m.text_content_id
WHERE db.in_inbox AND db.status <> 'DELETED'
ORDER BY tm.t DESC;
GRANT SELECT ON msgs.admin_inbox TO :dbuser;
--
-- Admin outbox
--
CREATE VIEW msgs.admin_outbox
AS SELECT db.id , db.admin_id , TRUE AS read ,
'ADM'::TEXT AS sender_type , db.admin_id AS sender_id ,
a.appear_as AS sender_name , r.receiver_type ,
( CASE
WHEN r.receiver_type = 'EMP'
THEN r.empire_id
ELSE r.admin_id
END ) AS receiver_id , r.name AS receiver_name ,
FALSE AS internal_message ,
tm.id AS content_id ,
tm.t AS r_time
FROM msgs.admin_delivery db
INNER JOIN admin.administrators a ON a.id = db.admin_id
INNER JOIN msgs.messages m ON m.id = db.message_id
INNER JOIN msgs.receivers r ON r.id = m.receiver_id
INNER JOIN msgs.text_messages tm ON tm.id = m.text_content_id
WHERE NOT db.in_inbox AND db.status <> 'DELETED'
ORDER BY tm.t DESC;
GRANT SELECT ON msgs.admin_outbox TO :dbuser;
--
-- Sends a message from an administrator to a target
--
-- Parameters:
-- a_id Administrator sending a message
-- to_type Type of message target (empire or admin)
-- to_name Name of the message target
-- ttl_txt Title of the message
-- cnt_txt Contents of the message
-- do_send Whether the message should actually be sent (used to verify target existence)
--
-- Returns:
-- err_code Error code:
-- 0 success
-- 1 unknown target
--
CREATE OR REPLACE FUNCTION msgs.send_admin_message( a_id INT , to_type receiver_type , to_name TEXT , ttl_txt TEXT ,
cnt_txt TEXT , do_send BOOLEAN , OUT err_code INT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
tg_id INT;
s_meth TEXT;
BEGIN
-- Find target and sending method
IF to_type = 'ADM'
THEN
s_meth := 'toadmin';
SELECT INTO tg_id id FROM admin.administrators
WHERE lower( appear_as ) = lower( to_name );
ELSEIF to_type = 'EMP'
THEN
s_meth := 'toempire';
SELECT INTO tg_id id FROM naming.empire_names n
INNER JOIN emp.empires e ON e.name_id = n.id
WHERE lower( name ) = lower( to_name );
ELSE
err_code := 1;
RETURN;
END IF;
IF NOT FOUND
THEN
err_code := 1;
RETURN;
ELSEIF to_type = 'EMP' AND do_send
THEN
PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Sending message "' || ttl_txt
|| '" to empire #' || tg_id || ' ("' || to_name || '")' );
END IF;
-- Send message (or not)
IF do_send
THEN
PERFORM sys.write_log( 'Messages' , 'DEBUG'::log_level , 'Delivering message from admin #' || a_id
|| ' using method ' || s_meth || ' with target identifier ' || tg_id || ' (title text null? '
|| ( ttl_txt IS NULL ) || ' ; content text null? ' || (cnt_txt IS NULL) || ')' );
EXECUTE 'SELECT msgs.deliver_admin_' || s_meth || '( $1 , $2 , $3 , $4 )'
USING a_id , tg_id , ttl_txt , cnt_txt;
ELSE
PERFORM sys.write_log( 'Messages' , 'DEBUG'::log_level , 'Simulated message delivery from admin #' || a_id
|| ' using method ' || s_meth || ' with target identifier ' || tg_id || ' (title text null? '
|| ( ttl_txt IS NULL ) || ' ; content text null? ' || (cnt_txt IS NULL) || ')' );
END IF;
err_code := 0;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION msgs.send_admin_message( INT , receiver_type , TEXT , TEXT , TEXT , BOOLEAN ) TO :dbuser;
--
-- Marks specific messages as read in an admin's inbox
--
-- Parameters:
-- a_id Admin identifier
-- m_ids Message identifiers
--
CREATE OR REPLACE FUNCTION msgs.admin_mark_read( a_id INT , m_ids BIGINT[] )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
UPDATE msgs.admin_delivery
SET status = 'READ'
WHERE admin_id = $1 AND status = 'UNREAD' AND id = ANY( $2 ) AND in_inbox
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION msgs.admin_mark_read( INT , BIGINT[] ) TO :dbuser;
--
-- Marks all messages as read in an admin's inbox
--
-- Parameters:
-- a_id Admin identifier
-- m_ids Message identifiers
--
CREATE OR REPLACE FUNCTION msgs.admin_mark_read( a_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
UPDATE msgs.admin_delivery
SET status = 'READ'
WHERE admin_id = $1 AND status = 'UNREAD' AND in_inbox
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION msgs.admin_mark_read( INT ) TO :dbuser;
--
-- Marks specific messages as unread in an admin's inbox
--
-- Parameters:
-- a_id Admin identifier
-- m_ids Message identifiers
--
CREATE OR REPLACE FUNCTION msgs.admin_mark_unread( a_id INT , m_ids BIGINT[] )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
UPDATE msgs.admin_delivery
SET status = 'UNREAD'
WHERE admin_id = $1 AND status = 'READ' AND id = ANY( $2 ) AND in_inbox
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION msgs.admin_mark_unread( INT , BIGINT[] ) TO :dbuser;
--
-- Marks all messages as unread in an admin's inbox
--
-- Parameters:
-- a_id Admin identifier
-- m_ids Message identifiers
--
CREATE OR REPLACE FUNCTION msgs.admin_mark_unread( a_id INT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
UPDATE msgs.admin_delivery
SET status = 'UNREAD'
WHERE admin_id = $1 AND status = 'READ' AND in_inbox
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION msgs.admin_mark_unread( INT ) TO :dbuser;
--
-- Marks specific messages as deleted in an admin's inbox or outbox
--
-- Parameters:
-- a_id Admin identifier
-- inbox Whether the affected messages are in the admin's inbox or in its outbox
-- m_ids Message identifiers
--
CREATE OR REPLACE FUNCTION msgs.admin_delete( a_id INT , inbox BOOLEAN , m_ids BIGINT[] )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
UPDATE msgs.admin_delivery
SET status = 'DELETED'
WHERE admin_id = $1 AND status <> 'DELETED' AND id = ANY( $3 ) AND in_inbox = $2
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION msgs.admin_delete( INT , BOOLEAN , BIGINT[] ) TO :dbuser;
--
-- Marks all messages as deleted in an admin's inbox or outbox
--
-- Parameters:
-- e_id Admin identifier
-- inbox Whether the affected messages are in the admin's inbox or in its outbox
-- m_ids Message identifiers
--
CREATE OR REPLACE FUNCTION msgs.admin_delete( e_id INT , inbox BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
UPDATE msgs.admin_delivery
SET status = 'DELETED'
WHERE admin_id = $1 AND status <> 'DELETED' AND in_inbox = $2
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION msgs.admin_delete( INT , BOOLEAN ) TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- VIEWS/FUNCTIONS USED BY THE E-MAIL NOTIFICATIONS / RECAP SYSTEM --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- General mailing information
--
CREATE VIEW msgs.last_unmailed_view
AS SELECT empire_id AS empire , max( id ) AS message
FROM msgs.empire_delivery
WHERE NOT emailed
GROUP BY empire_id;
CREATE VIEW msgs.last_unrecaped_view
AS SELECT empire_id AS empire , max( id ) AS message
FROM msgs.empire_delivery
WHERE NOT recaped
GROUP BY empire_id;
CREATE VIEW msgs.mail_sender_view
AS SELECT e.name_id AS empire , en.name AS empire_name ,
lang.language AS language , addr.address AS address ,
pprv.value AS on_private , pall.value AS on_alliance ,
pint.value AS on_internal , padm.value AS on_admin ,
lum.message AS last_unmailed , lrm.message AS last_unrecaped ,
( emn.account_id IS NULL ) AS can_notify
FROM emp.empires e
LEFT OUTER JOIN msgs.last_unmailed_view lum
ON lum.empire = e.name_id
LEFT OUTER JOIN msgs.last_unrecaped_view lrm
ON lrm.empire = e.name_id
INNER JOIN naming.empire_names en ON en.id = e.name_id
INNER JOIN users.credentials cred ON cred.address_id = en.owner_id
INNER JOIN defs.languages lang ON lang.id = cred.language_id
INNER JOIN users.addresses addr ON addr.id = cred.address_id
INNER JOIN users.preferences_view pprv
ON pprv.account_id = addr.id AND pprv.pref_name = 'mailOnPM'
INNER JOIN users.preferences_view pall
ON pall.account_id = addr.id AND pall.pref_name = 'mailOnAlliance'
INNER JOIN users.preferences_view pint
ON pint.account_id = addr.id AND pint.pref_name = 'mailOnIM'
INNER JOIN users.preferences_view padm
ON padm.account_id = addr.id AND padm.pref_name = 'mailOnAdmin'
LEFT OUTER JOIN msgs.email_notifications emn
ON emn.account_id = addr.id;
CREATE OR REPLACE FUNCTION msgs.get_mail_data( )
RETURNS SETOF msgs.mail_sender_view
STRICT VOLATILE
SECURITY DEFINER
AS $$
DELETE FROM msgs.email_notifications
WHERE now() - last_sent >= '1h'::interval;
SELECT * FROM msgs.mail_sender_view;
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION msgs.get_mail_data( ) TO :dbuser;
--
-- Instant notifications view and update function
--
CREATE VIEW msgs.empire_instant
AS SELECT db.id , db.empire_id ,
( CASE
WHEN s.id IS NULL
THEN 'INT'
ELSE s.sender_type::TEXT
END ) AS sender_type ,
( CASE
WHEN s.id IS NULL
THEN NULL::INT
WHEN s.sender_type = 'EMP'
THEN s.empire_id
ELSE s.admin_id
END ) AS sender_id ,
s.name AS sender_name , r.receiver_type ,
( CASE
WHEN r.receiver_type = 'EMP'
THEN r.empire_id
WHEN r.receiver_type = 'ALL'
THEN r.alliance_id
ELSE r.admin_id
END ) AS receiver_id , r.name AS receiver_name ,
( tm.id IS NULL ) AS internal_message ,
( CASE
WHEN tm.id IS NULL
THEN evt.event_id
ELSE tm.id
END ) AS content_id ,
( CASE
WHEN tm.id IS NULL
THEN evt.real_time
ELSE tm.t
END ) AS r_time
FROM msgs.empire_delivery db
INNER JOIN msgs.messages m ON m.id = db.message_id
INNER JOIN msgs.receivers r ON r.id = m.receiver_id
LEFT OUTER JOIN msgs.senders s ON m.sender_id = s.id
LEFT OUTER JOIN events.events evt ON evt.event_id = m.event_content_id
LEFT OUTER JOIN msgs.text_messages tm ON tm.id = m.text_content_id
WHERE db.in_inbox AND db.status = 'UNREAD' AND NOT db.emailed
ORDER BY ( CASE
WHEN tm.id IS NULL
THEN evt.real_time
ELSE tm.t
END ) DESC;
GRANT SELECT ON msgs.empire_instant TO :dbuser;
CREATE OR REPLACE FUNCTION msgs.mark_instant_notifications( e_id INT , m_id BIGINT , sending BOOLEAN )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
UPDATE msgs.empire_delivery SET emailed = TRUE
WHERE empire_id = e_id AND id <= m_id;
IF sending
THEN
INSERT INTO msgs.email_notifications ( account_id )
SELECT owner_id FROM naming.empire_names WHERE id = e_id;
END IF;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION msgs.mark_instant_notifications( INT , BIGINT , BOOLEAN ) TO :dbuser;
--
-- Recaps view, update function and check function
--
CREATE VIEW msgs.empire_recap
AS SELECT db.id , db.empire_id ,
( CASE
WHEN s.id IS NULL
THEN 'INT'
ELSE s.sender_type::TEXT
END ) AS sender_type ,
( CASE
WHEN s.id IS NULL
THEN NULL::INT
WHEN s.sender_type = 'EMP'
THEN s.empire_id
ELSE s.admin_id
END ) AS sender_id ,
s.name AS sender_name , r.receiver_type ,
( CASE
WHEN r.receiver_type = 'EMP'
THEN r.empire_id
WHEN r.receiver_type = 'ALL'
THEN r.alliance_id
ELSE r.admin_id
END ) AS receiver_id , r.name AS receiver_name ,
( tm.id IS NULL ) AS internal_message ,
( CASE
WHEN tm.id IS NULL
THEN evt.event_id
ELSE tm.id
END ) AS content_id ,
( CASE
WHEN tm.id IS NULL
THEN evt.real_time
ELSE tm.t
END ) AS r_time
FROM msgs.empire_delivery db
INNER JOIN msgs.messages m ON m.id = db.message_id
INNER JOIN msgs.receivers r ON r.id = m.receiver_id
LEFT OUTER JOIN msgs.senders s ON m.sender_id = s.id
LEFT OUTER JOIN events.events evt ON evt.event_id = m.event_content_id
LEFT OUTER JOIN msgs.text_messages tm ON tm.id = m.text_content_id
WHERE db.in_inbox AND NOT db.recaped
ORDER BY ( CASE
WHEN tm.id IS NULL
THEN evt.real_time
ELSE tm.t
END ) DESC;
GRANT SELECT ON msgs.empire_recap TO :dbuser;
CREATE OR REPLACE FUNCTION msgs.mark_recaps( e_id INT , m_id BIGINT )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
UPDATE msgs.empire_delivery SET recaped = TRUE
WHERE empire_id = $1 AND id <= $2;
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION msgs.mark_recaps( INT , BIGINT ) TO :dbuser;
CREATE OR REPLACE FUNCTION msgs.is_recap_time( )
RETURNS BOOLEAN
STRICT VOLATILE
SECURITY DEFINER
AS $$
BEGIN
UPDATE sys.status SET last_msg_recap = now()
WHERE now() - last_msg_recap > '1d'::INTERVAL;
RETURN FOUND;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION msgs.is_recap_time( ) TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- CLEANUP FUNCTION --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
CREATE OR REPLACE FUNCTION msgs.cleanup()
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DELETE FROM msgs.empire_delivery
WHERE emailed AND recaped AND status = 'DELETED';
DELETE FROM msgs.admin_delivery
WHERE emailed AND status = 'DELETED';
DELETE FROM msgs.messages WHERE id IN (
SELECT m.id FROM msgs.messages m
LEFT OUTER JOIN msgs.empire_delivery ed ON m.id = ed.message_id
LEFT OUTER JOIN msgs.admin_delivery ad ON m.id = ad.message_id
WHERE ad.id IS NULL AND ed.id IS NULL
);
DELETE FROM msgs.receivers WHERE id IN (
SELECT r.id FROM msgs.receivers r
LEFT OUTER JOIN msgs.messages m ON m.receiver_id = r.id
WHERE m.id IS NULL
);
DELETE FROM msgs.senders WHERE id IN (
SELECT s.id FROM msgs.senders s
LEFT OUTER JOIN msgs.messages m ON m.sender_id = s.id
WHERE m.id IS NULL
);
DELETE FROM msgs.text_messages WHERE id IN (
SELECT t.id FROM msgs.text_messages t
LEFT OUTER JOIN msgs.messages m ON m.text_content_id = t.id
WHERE m.id IS NULL
);
DELETE FROM events.events WHERE event_id IN (
SELECT e.event_id FROM events.events e
LEFT OUTER JOIN msgs.messages m ON m.event_content_id = e.event_id
WHERE m.id IS NULL AND e.status = 'SENT'
);
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION msgs.cleanup( ) TO :dbuser;