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/075-session-functions.sql

314 lines
11 KiB
MySQL
Raw Normal View History

2018-10-23 09:38:02 +02:00
-- LegacyWorlds Beta 6
-- PostgreSQL database scripts
--
-- User sessions functions
--
-- Copyright(C) 2004-2010, DeepClone Development
-- --------------------------------------------------------
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- MAIN SESSION VIEW --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
CREATE VIEW users.sessions
AS SELECT s.* , e.ended , e.end_type , c.name AS client_name , c.exclusive
FROM users.session_starts s
INNER JOIN defs.session_clients c ON c.id = s.client_id
LEFT OUTER JOIN users.session_ends e ON s.id = e.id
ORDER BY e.ended DESC NULLS FIRST , s.started DESC;
GRANT SELECT ON users.sessions TO :dbuser;
CREATE VIEW users.last_session
AS SELECT credentials_id , max( id ) AS session_id
FROM users.session_starts
GROUP BY credentials_id;
CREATE VIEW users.last_online
AS SELECT ls.credentials_id , ( CASE WHEN se.id IS NULL THEN now() ELSE se.ended END ) AS t
FROM users.last_session ls
LEFT OUTER JOIN users.session_ends se ON se.id = ls.session_id;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- SESSION MANAGEMENT FUNCTIONS --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- Marks all active sessions as terminated due to server restart
--
CREATE OR REPLACE FUNCTION users.sessions_server_restart( )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
INSERT INTO users.session_ends( id , end_type )
SELECT s.id , 'SERVER'::session_termination_type
FROM users.session_starts s
LEFT OUTER JOIN users.session_ends e USING ( id )
WHERE e.id IS NULL;
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION users.sessions_server_restart( ) TO :dbuser;
--
-- Registers a session's initialisation
--
-- Parameters:
-- c_id Credentials identifier
-- s_name Session name
-- c_type Client type name
-- s_addr Session address
--
-- Returns:
-- s_id Session identifier
--
CREATE OR REPLACE FUNCTION users.sessions_login( c_id INT , s_name TEXT , c_type TEXT , s_addr TEXT , OUT s_id BIGINT )
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
cl_id INT;
excl BOOLEAN;
as_id BIGINT;
as_nm TEXT;
BEGIN
-- Get client type parameters
SELECT INTO cl_id , excl id , exclusive
FROM defs.session_clients
WHERE name = c_type;
IF NOT FOUND
THEN
RAISE EXCEPTION 'Client session type "%" not found' , c_type;
END IF;
-- Close all active, exclusive sessions from the same user if the new session is exclusive
IF excl
THEN
FOR as_id , as_nm IN SELECT s.id , s.session
FROM users.session_starts s
INNER JOIN defs.session_clients c
ON s.client_id = c.id AND c.exclusive
LEFT OUTER JOIN users.session_ends e ON s.id = e.id
WHERE s.credentials_id = c_id AND e.id IS NULL
FOR UPDATE OF s
LOOP
PERFORM users.write_log( c_id , 'WARNING'::log_level , 'Terminating exclusive session "' || as_nm
|| '" due to new exlusive session' );
INSERT INTO users.session_ends ( id , end_type )
VALUES ( as_id , 'EXCLUSIVE'::session_termination_type );
END LOOP;
END IF;
-- Add new session
INSERT INTO users.session_starts ( credentials_id , client_id , session , from_address )
VALUES ( c_id , cl_id , s_name , s_addr )
RETURNING id INTO s_id;
PERFORM users.write_log( c_id , 'DEBUG'::log_level , 'Logged in from ' || s_addr
|| ' with client ' || c_type || '; session #' || s_id );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION users.sessions_login( INT , TEXT , TEXT , TEXT ) TO :dbuser;
--
-- Terminates a session
--
-- Parameters:
-- s_id Session identifier
-- e_type Session end type
--
CREATE OR REPLACE FUNCTION users.sessions_terminate( s_id BIGINT , e_type session_termination_type )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
c_id INT;
BEGIN
-- Get user identifier
SELECT INTO c_id s.credentials_id
FROM users.session_starts s
LEFT OUTER JOIN users.session_ends e USING ( id )
WHERE s.id = s_id AND e.id IS NULL
FOR UPDATE OF s;
IF NOT FOUND
THEN
RETURN;
END IF;
-- Terminate session
INSERT INTO users.session_ends ( id , end_type )
VALUES ( s_id , e_type );
PERFORM users.write_log( c_id , 'DEBUG'::log_level , 'Session #' || s_id
|| ' ended, termination type: ' || e_type );
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION users.sessions_terminate( BIGINT , session_termination_type ) TO :dbuser;
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- INACTIVITY CHECKS AND SESSION CLEAN-UP --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
-- --------------------------------------------------------------------------------------------------------------------------------------------------------------- --
--
-- User account record, used to send e-mails
--
CREATE TYPE inactive_account_record AS (
id INT ,
address TEXT ,
language TEXT
);
--
-- Checks for accounts that should receive an inactivity warning e-mail
--
-- Returns:
-- A set of user account records
--
CREATE OR REPLACE FUNCTION users.check_inactivity_emails()
RETURNS SETOF inactive_account_record
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
in_units BIGINT;
in_mail BIGINT;
in_time INTERVAL;
a_rec inactive_account_record;
BEGIN
in_units := floor( sys.get_constant( 'accounts.inactivity.units' ) );
in_mail := floor( sys.get_constant( 'accounts.inactivity.warningMail' ) );
in_time := ( (in_units * in_mail ) || 's' )::INTERVAL;
FOR a_rec IN SELECT cr.address_id AS id , ad.address , lg.language
FROM users.last_online lo
INNER JOIN users.credentials cr ON lo.credentials_id = cr.address_id
INNER JOIN users.addresses ad ON ad.id = cr.address_id
INNER JOIN defs.languages lg ON lg.id = cr.language_id
INNER JOIN users.active_accounts aa ON aa.credentials_id = lo.credentials_id
LEFT OUTER JOIN users.vacations vac ON vac.account_id = lo.credentials_id
LEFT OUTER JOIN users.inactivity_emails im ON im.account_id = lo.credentials_id
WHERE vac IS NULL AND im IS NULL AND now() - lo.t > in_time
FOR UPDATE OF cr , aa , ad
LOOP
INSERT INTO users.inactivity_emails ( account_id ) VALUES ( a_rec.id );
PERFORM users.write_log( a_rec.id , 'INFO'::log_level , 'Sending inactivity warning e-mail' );
RETURN NEXT a_rec;
END LOOP;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION users.check_inactivity_emails() TO :dbuser;
--
-- Removes inactivity e-mail records when users have logged on *after* the e-mail was sent
-- Disables inactive accounts, and lists them
--
CREATE OR REPLACE FUNCTION users.check_inactivity( )
RETURNS SETOF inactive_account_record
STRICT VOLATILE
SECURITY DEFINER
AS $$
DECLARE
in_units BIGINT;
in_drop BIGINT;
in_time INTERVAL;
a_rec RECORD;
r_rec inactive_account_record;
BEGIN
in_units := floor( sys.get_constant( 'accounts.inactivity.units' ) );
in_drop := floor( sys.get_constant( 'accounts.inactivity.deletion' ) );
in_time := ( (in_units * in_drop ) || 's' )::INTERVAL;
-- Delete inactivity email records for players who've logged in since the mail was sent
DELETE FROM users.inactivity_emails WHERE account_id IN (
SELECT lo.credentials_id
FROM users.last_online lo
INNER JOIN users.inactivity_emails im
ON im.account_id = lo.credentials_id AND im.mail_sent <= lo.t
);
-- Disable inactive user accounts
FOR a_rec IN SELECT cr.address_id AS id , ad.address , lg.language , e.name_id AS e_id
FROM users.inactivity_emails im
INNER JOIN users.credentials cr ON im.account_id = cr.address_id
INNER JOIN users.active_accounts aa ON aa.credentials_id = im.account_id
INNER JOIN users.addresses ad ON ad.id = cr.address_id
INNER JOIN defs.languages lg ON lg.id = cr.language_id
INNER JOIN naming.empire_names en ON en.owner_id = cr.address_id
INNER JOIN emp.empires e ON e.name_id = en.id
WHERE now() - im.mail_sent > in_time
FOR UPDATE OF cr , aa , ad , lg , en , e
LOOP
PERFORM users.write_log( a_rec.id , 'INFO'::log_level , 'Disabling account due to inactivity' );
PERFORM emp.delete_empire( a_rec.e_id );
DELETE FROM users.active_accounts WHERE credentials_id = a_rec.id;
INSERT INTO users.inactive_accounts ( credentials_id , since , status )
VALUES ( a_rec.id , now() - '1s'::INTERVAL , 'PROCESSED' );
r_rec := ( a_rec.id , a_rec.address, a_rec.language );
RETURN NEXT r_rec;
END LOOP;
END;
$$ LANGUAGE plpgsql;
GRANT EXECUTE ON FUNCTION users.check_inactivity() TO :dbuser;
--
-- Destroys old, inactive accounts
--
CREATE OR REPLACE FUNCTION users.delete_old_accounts( )
RETURNS VOID
STRICT VOLATILE
SECURITY DEFINER
AS $$
DELETE FROM users.addresses WHERE id IN (
SELECT ia.credentials_id
FROM users.inactive_accounts ia
LEFT OUTER JOIN admin.admin_credentials ac USING ( credentials_id )
LEFT OUTER JOIN admin.administrators ad ON ad.id = ac.administrator_id
WHERE now() - since >= '6 months'::INTERVAL AND ( ad IS NULL OR ad.privileges = 0 )
);
$$ LANGUAGE SQL;
GRANT EXECUTE ON FUNCTION users.delete_old_accounts() TO :dbuser;