-- LegacyWorlds Beta 6 -- PostgreSQL database scripts -- -- Functions and views to manage administrative accounts -- -- Copyright(C) 2004-2010, DeepClone Development -- -------------------------------------------------------- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- ADMINISTRATOR MANAGEMENT FUNCTIONS -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- -- Creates an administrative user -- -- Parameters: -- u_addr User account address -- a_name Administrative name -- privs Administrative privileges -- -- Returns: -- err_code Error code: -- 0 success -- 1 unknown user -- 2 invalid user status -- 3 name already in use -- 4 user already has admin access -- admin_id Administrator ID or NULL on failure -- CREATE OR REPLACE FUNCTION admin.create_admin( IN u_addr TEXT , IN a_name TEXT , IN privs INT , OUT err_code INT , OUT admin_id INT ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE u_id INT; u_stat TEXT; p_sha1 TEXT; p_md5 TEXT; BEGIN -- Get user ID, status and password hashes SELECT INTO u_id , u_stat , p_sha1 , p_md5 id , status , pass_sha1 , pass_md5 FROM users.accounts_view WHERE address = lower( u_addr ); IF NOT FOUND THEN err_code := 1; RETURN; ELSEIF u_stat IN ( 'UNCONFIRMED' , 'BANNED' ) THEN err_code := 2; RETURN; END IF; -- Try adding the admin's record BEGIN INSERT INTO admin.administrators ( appear_as , pass_md5 , pass_sha1 , privileges ) VALUES ( a_name , p_md5 , p_sha1 , privs ) RETURNING id INTO admin_id; EXCEPTION WHEN unique_violation THEN err_code := 3; RETURN; END; -- Add the admin <-> user relation BEGIN INSERT INTO admin.admin_credentials ( administrator_id , credentials_id ) VALUES ( admin_id , u_id ); err_code := 0; PERFORM admin.write_log( admin_id , 'INFO'::log_level , 'Administrator ' || a_name || ' created' ); EXCEPTION WHEN unique_violation THEN DELETE FROM admin.administrators WHERE id = admin_id; err_code := 4; admin_id := NULL; END; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION admin.create_admin( TEXT, TEXT , INT ) TO :dbuser; -- -- Type indicating the result of a connection attempt -- CREATE TYPE admin_connection_result AS ENUM( 'SUCCESS' , 'PASSWORD' , 'INACTIVE' ); -- -- Log a connection attempt -- -- Parameters: -- a_id Administrator identifier -- c_res Connection attempt result -- addr IP address -- CREATE OR REPLACE FUNCTION admin.log_connection( a_id INT , c_res admin_connection_result , addr TEXT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ BEGIN IF c_res = 'SUCCESS' THEN PERFORM admin.write_log( a_id , 'DEBUG'::log_level , 'Successful login attempt from ' || addr ); ELSEIF c_res = 'PASSWORD' THEN PERFORM admin.write_log( a_id , 'WARNING'::log_level , 'Failed login attempt from ' || addr || ' (incorrect password)' ); ELSEIF c_res = 'INACTIVE' THEN PERFORM admin.write_log( a_id , 'WARNING'::log_level , 'Failed login attempt from ' || addr || ' (inactive administrator)' ); ELSE RAISE EXCEPTION 'Unknown connection attempt result value: %' , c_res; END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION admin.log_connection( INT , admin_connection_result , TEXT ) TO :dbuser; -- -- Log a disconnection -- -- Parameters: -- a_id Administrator identifier -- CREATE OR REPLACE FUNCTION admin.log_disconnection( a_id INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ BEGIN PERFORM admin.write_log( a_id , 'DEBUG'::log_level , 'Administrator disconnected' ); END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION admin.log_disconnection( INT ) TO :dbuser; -- -- Modifies an administrator's password -- -- Parameters: -- a_id Administrator identifier -- p_sha1 SHA-1 hash of the new password -- p_md5 MD5 hash of the new password -- -- Returns: -- success Whether the operation was successful -- CREATE OR REPLACE FUNCTION admin.set_password( a_id INT , p_sha1 TEXT , p_md5 TEXT , OUT success BOOLEAN ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE u_sha1 TEXT; u_md5 TEXT; BEGIN SELECT INTO u_sha1 , u_md5 c.pass_sha1 , c.pass_md5 FROM admin.admins_view a INNER JOIN users.credentials c ON c.address_id = a.account_id WHERE a.administrator_id = a_id AND a.active; success := ( FOUND AND u_sha1 <> p_sha1 AND u_md5 <> p_md5 ); IF success THEN UPDATE admin.administrators SET pass_sha1 = p_sha1 , pass_md5 = p_md5 WHERE id = a_id; END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION admin.set_password( INT , TEXT , TEXT ) TO :dbuser; -- -- Resets an administrator's password to his/her player account password -- -- Parameters: -- a_id Administrator identifier -- su_id Superuser identifier -- -- Returns: -- success Whether the operation was successful -- CREATE OR REPLACE FUNCTION admin.reset_password( a_id INT , su_id INT , OUT success BOOLEAN ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE u_sha1 TEXT; u_md5 TEXT; a_name TEXT; BEGIN SELECT INTO u_sha1 , u_md5 , a_name c.pass_sha1 , c.pass_md5 , a.name FROM admin.admins_view a INNER JOIN users.credentials c ON c.address_id = a.account_id WHERE a.administrator_id = a_id AND a.active; success := FOUND; IF success THEN UPDATE admin.administrators SET pass_sha1 = u_sha1 , pass_md5 = u_md5 WHERE id = a_id; PERFORM admin.write_log( su_id , 'INFO'::log_level , 'Reset password of administrator ' || a_name ); END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION admin.reset_password( INT , INT ) TO :dbuser; -- -- Modifies an administrator's privileges -- -- Parameters: -- a_id Administrator identifier -- su_id Superuser identifier -- n_privs New privileges -- -- Returns: -- success Whether the operation was successful -- CREATE OR REPLACE FUNCTION admin.set_privileges( a_id INT , su_id INT , n_privs INT , OUT success BOOLEAN ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE a_name TEXT; o_privs INT; BEGIN SELECT INTO a_name , o_privs a.name , a.privileges FROM admin.admins_view a WHERE a.administrator_id = a_id AND a.address IS NOT NULL; success := FOUND; IF success AND n_privs <> o_privs THEN UPDATE admin.administrators SET privileges = n_privs WHERE id = a_id; PERFORM admin.write_log( su_id , 'INFO'::log_level , 'Set privileges of administrator ' || a_name || ' from ' || o_privs || ' to ' || n_privs ); END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION admin.set_privileges( INT , INT , INT ) TO :dbuser; -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- ADMINISTRATOR VIEWS -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- -- Active administrators -- CREATE VIEW admin.admins_view AS SELECT adm.id AS administrator_id , adm.appear_as AS name , adm.privileges AS privileges , adm.pass_sha1 , adm.pass_md5 , addr.id AS account_id , addr.address AS address , ( addr.id IS NOT NULL AND privileges <> 0 ) AS active , ( adm.pass_sha1 = cred.pass_sha1 AND adm.pass_md5 = cred.pass_md5 ) AS pass_change_required FROM admin.administrators adm LEFT OUTER JOIN admin.admin_credentials ac ON ac.administrator_id = adm.id LEFT OUTER JOIN users.credentials cred ON cred.address_id = ac.credentials_id LEFT OUTER JOIN users.addresses addr ON addr.id = ac.credentials_id; GRANT SELECT ON admin.admins_view TO :dbuser; -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- BANHAMMER FUNCTIONS -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- -- Creates a ban request -- -- Parameters: -- a_id Administrator identifier -- u_id User identifier -- r_txt Reason for the ban request -- -- Returns: -- Whether the operation was successful or not -- CREATE OR REPLACE FUNCTION admin.add_ban_request( a_id INT , u_id INT , r_txt TEXT ) RETURNS BOOLEAN STRICT VOLATILE SECURITY INVOKER AS $$ DECLARE ban_id INT; BEGIN INSERT INTO admin.ban_requests ( requested_by , reason ) VALUES ( a_id , r_txt ) RETURNING id INTO ban_id; BEGIN INSERT INTO admin.active_ban_requests( request_id , credentials_id ) VALUES( ban_id , u_id ); RETURN TRUE; EXCEPTION WHEN unique_violation THEN DELETE FROM admin.ban_requests WHERE id = ban_id; RETURN FALSE; END; END; $$ LANGUAGE plpgsql; -- -- Creates a ban request using an email address as the source -- -- Parameters: -- a_id Administrator identifier -- u_addr Target user's address -- r_txt Reason for the ban request -- -- Returns: -- err_code Error code: -- 0 success -- 1 user not found -- 2 duplicate request -- CREATE OR REPLACE FUNCTION admin.request_ban_on_address( a_id INT , u_addr TEXT , r_txt TEXT , OUT err_code INT ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE u_id INT; BEGIN SELECT INTO u_id id FROM users.accounts_view WHERE address = u_addr; IF NOT FOUND THEN err_code := 1; RETURN; END IF; IF admin.add_ban_request( a_id , u_id , r_txt ) THEN PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Requested ban of user #' || u_id || ' (address: ' || u_addr || ')' ); err_code := 0; ELSE err_code := 2; END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION admin.request_ban_on_address( INT , TEXT, TEXT ) TO :dbuser; -- -- Creates a ban request using an empire name as the source -- -- Parameters: -- a_id Administrator identifier -- u_emp Target user's empire name -- r_txt Reason for the ban request -- -- Returns: -- err_code Error code: -- 0 success -- 1 user not found -- 2 duplicate request -- CREATE OR REPLACE FUNCTION admin.request_ban_on_empire( a_id INT , u_emp TEXT , r_txt TEXT , OUT err_code INT ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE u_id INT; BEGIN SELECT INTO u_id owner_id FROM naming.empire_names WHERE lower(name) = lower(u_emp); IF NOT FOUND THEN err_code := 1; RETURN; END IF; IF admin.add_ban_request( a_id , u_id , r_txt ) THEN PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Requested ban of user #' || u_id || ' (empire name: ' || u_emp || ')' ); err_code := 0; ELSE err_code := 2; END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION admin.request_ban_on_empire( INT , TEXT, TEXT ) TO :dbuser; -- -- Rejects a ban request -- -- Parameters: -- a_id Administrator identifier -- b_id Ban request identifier -- r_txt Rejection reason -- CREATE OR REPLACE FUNCTION admin.reject_ban_request( a_id INT , b_id INT , r_txt TEXT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE u_id INT; BEGIN -- Make sure the request exists and hasn't been validated SELECT INTO u_id credentials_id FROM admin.active_ban_requests WHERE request_id = b_id AND NOT validated FOR UPDATE; IF NOT FOUND THEN RETURN; END IF; PERFORM * FROM admin.ban_requests WHERE id = b_id FOR UPDATE; -- Insert archive entry INSERT INTO admin.archived_ban_requests( request_id , credentials_id ) VALUES ( b_id , u_id ); INSERT INTO admin.rejected_ban_requests( request_id , rejected_by , reason ) VALUES ( b_id , a_id , r_txt ); DELETE FROM admin.active_ban_requests WHERE request_id = b_id; PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Rejected ban of user #' || u_id ); END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION admin.reject_ban_request( INT , INT , TEXT ) TO :dbuser; -- -- Confirms a ban request -- -- Parameters: -- a_id Administrator identifier -- b_id Ban request identifier -- -- Returns: -- success Whether the operation was successful -- addr User's email address -- lang User's language -- r_txt Reason for the ban -- CREATE OR REPLACE FUNCTION admin.confirm_ban_request( a_id INT , b_id INT , OUT success BOOLEAN , OUT addr TEXT , OUT lang TEXT , OUT r_txt TEXT ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE u_id INT; br_id INT; BEGIN -- Make sure there is an active, unvalidated ban request SELECT INTO u_id credentials_id FROM admin.active_ban_requests WHERE request_id = b_id AND NOT validated FOR UPDATE; IF NOT FOUND THEN success := FALSE; RETURN; END IF; -- Make sure the request was created by another admin SELECT INTO br_id , r_txt requested_by , reason FROM admin.ban_requests WHERE id = b_id AND requested_by <> a_id FOR UPDATE; IF NOT FOUND THEN success := FALSE; RETURN; END IF; -- Mark request as validated INSERT INTO admin.validated_ban_requests ( request_id , validated_by ) VALUES ( b_id , a_id ); UPDATE admin.active_ban_requests SET validated = TRUE WHERE request_id = b_id; -- Update account PERFORM * FROM users.credentials WHERE address_id = u_id FOR UPDATE; LOOP UPDATE users.inactive_accounts SET since = now( ) , status = 'PROCESSED' WHERE credentials_id = u_id; EXIT WHEN FOUND; BEGIN INSERT INTO users.inactive_accounts ( credentials_id , since , status ) VALUES ( u_id , now() , 'PROCESSED' ); EXIT; EXCEPTION WHEN unique_violation THEN -- Do nothing END; END LOOP; -- Insert ban entry INSERT INTO users.bans ( account_id , ban_id ) VALUES( u_id , b_id ); -- Set ban reason LOOP UPDATE users.reasons SET reason = r_txt WHERE account_id = u_id; EXIT WHEN FOUND; BEGIN INSERT INTO users.reasons( account_id , reason ) VALUES ( u_id , r_txt ); EXIT; EXCEPTION WHEN unique_violation THEN -- Do nothing END; END LOOP; success := TRUE; SELECT INTO addr , lang a.address , l.language FROM users.credentials c INNER JOIN users.addresses a ON a.id = c.address_id INNER JOIN defs.languages l ON l.id = c.language_id WHERE c.address_id = u_id; PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Confirmed ban request on user #' || u_id ); END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION admin.confirm_ban_request( INT , INT ) TO :dbuser; -- -- Lifts an existing ban -- -- Parameters: -- a_id Administrator identifier -- b_id Ban identifier -- -- Returns: -- success Whether the operation was successful -- addr User's email address -- lang User's language -- CREATE OR REPLACE FUNCTION admin.lift_ban( a_id INT , b_id INT , OUT success BOOLEAN , OUT addr TEXT , OUT lang TEXT ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE u_id INT; redeem BOOLEAN; BEGIN -- Find / lock the ban and user records SELECT INTO u_id , redeem ab.credentials_id , ( aa.credentials_id IS NOT NULL ) FROM admin.active_ban_requests ab INNER JOIN admin.ban_requests br ON br.id = ab.request_id INNER JOIN users.credentials c ON c.address_id = ab.credentials_id LEFT OUTER JOIN users.active_accounts aa ON aa.credentials_id = c.address_id WHERE ab.request_id = b_id AND ab.validated FOR UPDATE OF ab , br , c; IF NOT FOUND THEN success := FALSE; RETURN; END IF; -- Delete the ban and reason records, and redeem the account if possible DELETE FROM users.bans WHERE account_id = u_id; DELETE FROM users.reasons WHERE account_id = u_id; IF redeem THEN DELETE FROM users.inactive_accounts WHERE credentials_id = u_id; END IF; -- Delete active and validated ban entries DELETE FROM admin.validated_ban_requests WHERE request_id = b_id; DELETE FROM admin.active_ban_requests WHERE request_id = b_id; -- Insert archive records INSERT INTO admin.archived_ban_requests( request_id , credentials_id ) VALUES ( b_id , u_id ); INSERT INTO admin.rejected_ban_requests( request_id , rejected_by , reason ) VALUES ( b_id , a_id , '(ban lifted)' ); success := TRUE; SELECT INTO addr , lang a.address , l.language FROM users.credentials c INNER JOIN users.addresses a ON a.id = c.address_id INNER JOIN defs.languages l ON l.id = c.language_id WHERE c.address_id = u_id; PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Ban on user #' || u_id || ' has been lifted' || (CASE WHEN redeem THEN ' (empire redeemed)' ELSE '' END) ); END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION admin.lift_ban( INT , INT ) TO :dbuser; -- -- Causes ban requests to expire -- CREATE OR REPLACE FUNCTION admin.expire_ban_requests( ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE b_id INT; u_id INT; BEGIN FOR b_id , u_id IN SELECT br.id , ab.credentials_id FROM admin.ban_requests br INNER JOIN admin.active_ban_requests ab ON ab.request_id = br.id AND NOT validated WHERE now() - br.requested >= ( floor( sys.get_constant( 'accounts.banExpiration') ) || 's' )::INTERVAL FOR UPDATE LOOP INSERT INTO admin.archived_ban_requests ( request_id , credentials_id ) VALUES ( b_id , u_id ); DELETE FROM admin.active_ban_requests WHERE request_id = b_id; PERFORM sys.write_log( 'Bans' , 'INFO'::log_level , 'Ban request #' || b_id || ' (user account #' || u_id || ') expired' ); END LOOP; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION admin.expire_ban_requests( ) TO :dbuser; -- -- Checks for banned players who still have empires past the expiration delay -- and deletes the empires. -- -- Returns: -- Whether an empire was deleted -- CREATE OR REPLACE FUNCTION admin.delete_banned_empires( ) RETURNS BOOLEAN STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE e_id INT; a_id INT; BEGIN SELECT INTO e_id , a_id e.name_id , c.address_id FROM emp.empires e INNER JOIN naming.empire_names en ON en.id = e.name_id INNER JOIN users.credentials c ON c.address_id = en.owner_id INNER JOIN users.active_accounts aa ON aa.credentials_id = c.address_id INNER JOIN users.inactive_accounts ia ON ia.credentials_id = c.address_id INNER JOIN users.bans b ON b.account_id = ia.credentials_id WHERE now() - ia.since >= ( floor( sys.get_constant( 'accounts.banDelay') ) || 's' )::INTERVAL FOR UPDATE LIMIT 1; IF NOT FOUND THEN RETURN FALSE; END IF; -- Delete empire and active account record PERFORM emp.delete_empire( e_id ); DELETE FROM users.active_accounts WHERE credentials_id = a_id; PERFORM sys.write_log( 'Bans' , 'INFO'::log_level , 'Deleted empire #' || e_id || ' (user account #' || a_id || ')' ); RETURN TRUE; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION admin.delete_banned_empires( ) TO :dbuser; -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- VIEWS RELATED TO THE BANHAMMER -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- -- Pending requests -- CREATE VIEW admin.pending_bans AS SELECT r.id , r.requested_by AS requested_by_id , a.appear_as AS requested_by_name , r.reason , r.requested , ab.credentials_id AS account_id , ad.address AS account_mail FROM admin.ban_requests r INNER JOIN admin.active_ban_requests ab ON ab.request_id = r.id AND NOT ab.validated INNER JOIN admin.administrators a ON a.id = r.requested_by INNER JOIN users.addresses ad ON ad.id = ab.credentials_id; GRANT SELECT ON admin.pending_bans TO :dbuser; -- -- Expired / rejected ban requests -- CREATE VIEW admin.cancelled_bans AS SELECT r.id , r.requested_by AS requested_by_id , a.appear_as AS requested_by_name , r.reason , r.requested , ab.credentials_id AS account_id , ad.address AS account_mail , ab.updated , ( rb.request_id IS NULL ) AS expired , rb.rejected_by AS rejected_by_id , ra.appear_as AS rejected_by_name , rb.reason AS rejection_reason FROM admin.ban_requests r INNER JOIN admin.administrators a ON a.id = r.requested_by INNER JOIN admin.archived_ban_requests ab ON ab.request_id = r.id INNER JOIN users.addresses ad ON ad.id = ab.credentials_id LEFT OUTER JOIN admin.rejected_ban_requests rb ON rb.request_id = r.id LEFT OUTER JOIN admin.administrators ra ON ra.id = rb.rejected_by; GRANT SELECT ON admin.cancelled_bans TO :dbuser; -- -- Active bans -- CREATE VIEW admin.active_bans AS SELECT r.id , r.requested_by AS requested_by_id , a.appear_as AS requested_by_name , r.reason , r.requested , ab.credentials_id AS account_id , ad.address AS account_mail , vr.validated AS updated , ( ua.credentials_id IS NOT NULL ) AS redeemable , vr.validated_by AS validated_by_id , va.appear_as AS validated_by_name FROM admin.ban_requests r INNER JOIN admin.administrators a ON a.id = r.requested_by INNER JOIN admin.active_ban_requests ab ON ab.request_id = r.id AND validated INNER JOIN users.addresses ad ON ad.id = ab.credentials_id INNER JOIN admin.validated_ban_requests vr ON vr.request_id = r.id INNER JOIN admin.administrators va ON va.id = vr.validated_by LEFT OUTER JOIN users.active_accounts ua ON ua.credentials_id = ab.credentials_id; GRANT SELECT ON admin.active_bans TO :dbuser; -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- WARNING SYSTEM FUNCTIONS -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- -- Adds a warning to a player's account, triggering an automatic ban request if necessary -- -- Parameters: -- a_id Administrator identifier -- u_id Player identifier -- -- Returns: -- given Whether a warning was issued or not -- c_count Current amount of warnings for this player -- CREATE OR REPLACE FUNCTION admin.give_player_warning( a_id INT , u_id INT , OUT given BOOLEAN , OUT c_count INT ) STRICT VOLATILE SECURITY INVOKER AS $$ DECLARE last_rec TIMESTAMP WITHOUT TIME ZONE; BEGIN LOOP SELECT INTO c_count , last_rec warnings, last_received FROM admin.warnings WHERE credentials_id = u_id FOR UPDATE; IF FOUND THEN given := ( now() - last_rec >= ( floor(sys.get_constant('accounts.warnings.grace')) || 's' )::INTERVAL ); IF given THEN c_count := c_count + 1; UPDATE admin.warnings SET last_received = now( ) , warnings = c_count WHERE credentials_id = u_id; END IF; EXIT; END IF; BEGIN INSERT INTO admin.warnings ( credentials_id ) VALUES ( u_id ); given := TRUE; c_count := 1; EXIT; EXCEPTION WHEN unique_violation THEN -- Do nothing END; END LOOP; IF given THEN PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Warning given to user #' || u_id || ' (' || c_count || ' warning(s) total)' ); IF c_count >= sys.get_constant( 'accounts.warnings.autoBan' ) THEN IF admin.add_ban_request( a_id , u_id , 'Automatic ban after ' || c_count || ' warnings' ) THEN PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Added automatic ban for user ' || u_id ); END IF; END IF; END IF; END; $$ LANGUAGE plpgsql; -- -- Causes old warnings to expire -- CREATE OR REPLACE FUNCTION admin.expire_warnings( ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE e_time INTERVAL; g_time INTERVAL; BEGIN e_time := ( floor( sys.get_constant( 'accounts.warnings.expiration' ) * sys.get_constant( 'accounts.warnings.expiration.units' ) ) || 's' ) :: INTERVAL; g_time := ( floor(sys.get_constant('accounts.warnings.grace')) || 's' )::INTERVAL; UPDATE admin.warnings SET last_received = now( ) - g_time , warnings = warnings - 1 WHERE now() - last_received >= e_time AND warnings > 0; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION admin.expire_warnings( ) TO :dbuser; -- -- Finds out if it is time to send the administrative recap e-mails -- CREATE OR REPLACE FUNCTION admin.is_recap_time( OUT is_time TIMESTAMP WITHOUT TIME ZONE ) STRICT VOLATILE SECURITY DEFINER AS $$ BEGIN SELECT INTO is_time last_admin_recap FROM sys.status WHERE now() - last_admin_recap >= '12 hours'::INTERVAL FOR UPDATE; IF FOUND THEN UPDATE sys.status SET last_admin_recap = now( ); END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION admin.is_recap_time( ) TO :dbuser; -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- USERS VIEW -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- -- --------------------------------------------------------------------------------------------------------------------------------------------------------------- -- CREATE VIEW admin.user_empires AS SELECT en.* FROM emp.empires e INNER JOIN naming.empire_names en ON e.name_id = en.id; CREATE VIEW admin.users_list AS SELECT av.* , ue.id AS current_empire_id , ue.name AS current_empire , a1.id AS ban_req_id , a1.appear_as AS ban_req_name , a2.id AS ban_val_id , a2.appear_as AS ban_val_name , ( CASE WHEN w IS NULL THEN 0 ELSE w.warnings END ) AS warnings_count , w.last_received AS warnings_last FROM users.accounts_view av LEFT OUTER JOIN admin.user_empires ue ON ue.owner_id = av.id LEFT OUTER JOIN admin.ban_requests br ON br.id = av.ban_request_id LEFT OUTER JOIN admin.validated_ban_requests vbr ON vbr.request_id = br.id LEFT OUTER JOIN admin.administrators a1 ON a1.id = br.requested_by LEFT OUTER JOIN admin.administrators a2 ON a2.id = vbr.validated_by LEFT OUTER JOIN admin.warnings w ON w.credentials_id = av.id ORDER BY av.address; GRANT SELECT ON admin.users_list TO :dbuser;