-- LegacyWorlds Beta 6 -- PostgreSQL database scripts -- -- User management functions -- -- Copyright(C) 2004-2010, DeepClone Development -- -------------------------------------------------------- -- -- E-mail address creation -- CREATE OR REPLACE FUNCTION users.create_address ( addr TEXT ) RETURNS INT STRICT VOLATILE SECURITY INVOKER AS $$ DECLARE pk INT; BEGIN INSERT INTO users.addresses (address) VALUES (addr) RETURNING id INTO pk; RETURN pk; EXCEPTION WHEN unique_violation THEN RETURN NULL; END; $$ LANGUAGE plpgsql; -- -- Generates a random token. -- -- Parameters: -- len Length of the token -- -- Returns: -- the token -- CREATE OR REPLACE FUNCTION users.make_token( len INT ) RETURNS TEXT STRICT VOLATILE SECURITY INVOKER AS $$ DECLARE i INT; result TEXT; ok_chars CHAR ARRAY[16] := ARRAY['0','1','2','3','4','5','6','7','8','9','A','B','C','D','E','F','G','H','I','J','K','L','M','N','O','P','Q','R','S','T','U','V','W','X','Y','Z']; BEGIN result := ''; FOR i IN 1 .. len LOOP result := result || ok_chars[ 1 + floor( random() * 36 )::INT ]; END LOOP; RETURN result; END; $$ LANGUAGE plpgsql; -- -- Credentials creation -- -- Parameters: -- addr mail address -- lang selected language -- pmd5 MD5 hash of password -- psha1 SHA-1 hash of password -- -- Returns: -- err_code error code: -- 0 on success -- -1 if the address exists -- -2 if the language does not exist -- a_id the account's identifier -- CREATE OR REPLACE FUNCTION users.create_credentials ( addr TEXT , lang TEXT , pmd5 TEXT , psha1 TEXT , OUT err_code INT , OUT a_id INT) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE vkey TEXT; l_id INT; BEGIN -- Get language SELECT INTO l_id l.id FROM defs.languages l CROSS JOIN defs.strings s LEFT OUTER JOIN defs.translations t ON t.lang_id = l.id AND t.string_id = s.id WHERE l.language = lang GROUP BY l.id HAVING count( s.* ) = count( t.* ); IF NOT FOUND THEN err_code := -2; a_id := NULL; RETURN; END IF; -- Create address a_id := users.create_address( addr ); IF a_id IS NULL THEN err_code := -1; RETURN; END IF; -- Insert credentials INSERT INTO users.credentials (address_id, pass_md5, pass_sha1, credits, language_id) VALUES ( a_id , pmd5 , psha1 , floor( sys.get_constant( 'game.initialCredits' ) ) , l_id ); vkey := users.make_token(64); INSERT INTO users.validation_keys (credentials_id, token) VALUES ( a_id , vkey ); PERFORM users.write_log( a_id , 'INFO'::log_level , 'Account created; validation key: ' || vkey ); err_code := 0; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.create_credentials(TEXT,TEXT,TEXT,TEXT) TO :dbuser; -- -- Attempts to re-activate a disabled account -- -- Parameters: -- addr Account e-mail address -- -- Returns: -- success Whether the operation was successful -- a_id Account identifier -- CREATE OR REPLACE FUNCTION users.reactivate( IN addr TEXT , OUT success BOOLEAN , OUT a_id INT ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE vkey TEXT; BEGIN SELECT INTO a_id id FROM users.accounts_view WHERE address = addr AND status = 'DISABLED'; success := FOUND; IF success THEN vkey := users.make_token( 64 ); INSERT INTO users.validation_keys (credentials_id, token) VALUES ( a_id , vkey ); PERFORM users.write_log( a_id , 'INFO'::log_level , 'Account re-activation requested; validation key: ' || vkey ); END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.reactivate(TEXT) TO :dbuser; -- -- This function is called when an account's validation token cannot be sent. -- -- Parameters: -- a_id Account identifier -- CREATE OR REPLACE FUNCTION users.validation_mail_failure( IN a_id INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE st TEXT; BEGIN SELECT INTO st status FROM users.accounts_view WHERE id = a_id; IF st = 'UNCONFIRMED' THEN DELETE FROM users.addresses WHERE id = a_id; ELSEIF st = 'REACTIVATING' THEN DELETE FROM users.validation_keys WHERE credentials_id = a_id; ELSE RAISE EXCEPTION 'Invalid account status % (account #%)' , st , a_id; END IF; PERFORM sys.write_log( 'AccountManagement' , 'ERROR'::log_level , 'Account re-activation mail could not be sent for account #' || a_id || ', deleting validation key' ); END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.validation_mail_failure( INT ) TO :dbuser; -- -- Request password recovery -- -- Parameters: -- addr account mail address -- -- Returns: -- err_code error code: -- 0 on success, -- 1 if there's already a password recovery request for the account -- 2 if the account doesn't exist. -- a_id account identifier -- CREATE OR REPLACE FUNCTION users.request_password_recovery( IN addr TEXT , OUT err_code INT , OUT a_id INT) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE vkey TEXT; BEGIN SELECT INTO a_id ad.id FROM users.addresses ad INNER JOIN users.credentials c ON c.address_id = ad.id INNER JOIN users.accounts_view av ON av.id = ad.id WHERE ad.address = addr AND av.status IN ( 'ACTIVE' , 'VACATION' , 'START_VACATION' , 'QUITTING' ) FOR UPDATE OF ad , c; IF NOT FOUND THEN err_code := 2; ELSE vkey := users.make_token( 64 ); BEGIN INSERT INTO users.pwd_recovery_requests (credentials_id , token) VALUES ( a_id , vkey ); PERFORM users.write_log( a_id , 'INFO'::log_level , 'Password recovery requested; validation key: ' || vkey ); err_code := 0; EXCEPTION WHEN unique_violation THEN err_code := 1; a_id := NULL; END; END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.request_password_recovery( TEXT ) TO :dbuser; -- -- Confirm password recovery -- -- Parameters: -- umail account mail address -- tok recovery token -- pmd5 new password's MD5 hash -- psha1 new password's SHA-1 hash -- -- Returns: -- err_code error code: -- 0 on success -- 1 if the account doesn't exist, if the token is wrong or if the request is used -- 2 if the new password is the same as the user's administrative access -- a_id account identifier -- CREATE OR REPLACE FUNCTION users.confirm_password_recovery( IN umail TEXT, IN tok TEXT, IN pmd5 TEXT, IN psha1 TEXT , OUT err_code INT , OUT a_id INT ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE amd5 TEXT; asha1 TEXT; BEGIN SELECT INTO a_id, amd5, asha1 addr.id, admin.pass_md5 , admin.pass_sha1 FROM users.addresses addr INNER JOIN users.credentials creds ON creds.address_id = addr.id INNER JOIN users.pwd_recovery_requests req ON req.credentials_id = creds.address_id AND req.token = tok AND NOT req.used LEFT OUTER JOIN admin.admin_credentials acreds ON acreds.credentials_id = creds.address_id LEFT OUTER JOIN admin.administrators admin ON admin.id = acreds.administrator_id WHERE addr.address = umail FOR UPDATE OF creds , addr , req; IF NOT FOUND THEN err_code := 1; RETURN; ELSEIF amd5 IS NOT NULL AND amd5 = pmd5 AND asha1 = psha1 THEN err_code := 2; RETURN; END IF; UPDATE users.pwd_recovery_requests SET used = TRUE WHERE credentials_id = a_id; UPDATE users.credentials SET pass_md5 = pmd5 , pass_sha1 = psha1 WHERE address_id = a_id; PERFORM users.write_log( a_id , 'INFO'::log_level , 'Password recovery successful' ); err_code := 0; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.confirm_password_recovery( TEXT , TEXT , TEXT , TEXT ) TO :dbuser; -- -- Cancel password recovery request after a mail failure -- -- Parameters: -- a_id account identifier -- CREATE OR REPLACE FUNCTION users.cancel_password_recovery( a_id INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ BEGIN PERFORM users.write_log( a_id , 'ERROR'::log_level , 'Password recovery: could not send e-mail, aborting' ); DELETE FROM users.pwd_recovery_requests WHERE credentials_id = a_id; END; $$ LANGUAGE plpgsql; -- -- Request mail address change -- -- Parameters: -- cid account identifier -- nmail new address -- -- Returns: -- err_code 0 on success -- -1 if there's already such a request in the DB -- -2 if the mail address exists -- CREATE OR REPLACE FUNCTION users.request_address_change( cid INT , nmail TEXT , OUT err_code INT ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE vkey TEXT; BEGIN vkey := users.make_token( 64 ); INSERT INTO users.address_change_requests( credentials_id , address_id , token ) VALUES ( cid , users.create_address( nmail ) , vkey ); err_code := 0; PERFORM users.write_log( cid , 'INFO'::log_level , 'E-mail address change requested; validation key: ' || vkey ); EXCEPTION WHEN unique_violation THEN err_code := -1; WHEN not_null_violation THEN err_code := -2; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.request_address_change( INT , TEXT ) TO :dbuser; -- -- Confirm mail address change -- -- Parameters: -- cid account identifier -- tok validation token -- -- Returns: -- n_id The account's new identifier -- CREATE OR REPLACE FUNCTION users.confirm_address_change( cid INT , tok TEXT , OUT n_id INT ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE pk INT; npk INT; oaddr TEXT; BEGIN SELECT INTO pk, npk, oaddr addr.id , acr.address_id , addr.address FROM users.addresses addr, users.credentials creds, users.address_change_requests acr WHERE addr.id = cid AND creds.address_id = cid AND acr.credentials_id = cid AND acr.token = tok AND NOT acr.used FOR UPDATE; IF FOUND THEN UPDATE users.credentials SET address_id = npk WHERE address_id = pk; UPDATE users.address_change_requests SET used = TRUE WHERE credentials_id = npk; DELETE FROM users.addresses WHERE id = pk; n_id := npk; PERFORM users.write_log( npk , 'INFO'::log_level , 'E-mail address change confirmed (old address: ' || oaddr || ')' ); ELSE n_id := 0; END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.confirm_address_change( INT , TEXT ) TO :dbuser; -- -- Cancels an address change request -- -- Parameters: -- cid account identifier -- CREATE OR REPLACE FUNCTION users.cancel_address_change( cid INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ BEGIN UPDATE users.address_change_requests SET used = TRUE WHERE credentials_id = cid; PERFORM users.write_log( cid , 'INFO'::log_level , 'E-mail address change aborted' ); END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.cancel_address_change( INT ) TO :dbuser; -- -- Account validation -- -- /!\ Transaction rollback required if there is an error /!\ -- -- Parameters: -- addr Account email address -- vtoken Validation token -- empname Empire name -- plname Initial planet name -- -- Returns: -- account_error 0 on success -- 1 if the account's status is incorrect -- 2 if the validation token doesn't match -- empire_error 0 on success -- 1 if the name is banned -- 2 if the empire name is unavailable -- planet_error 0 on success -- 1 if the name is banned -- 2 if the planet name is unavailable -- CREATE OR REPLACE FUNCTION users.validate( addr TEXT , vtoken TEXT , empname TEXT , plname TEXT , OUT account_error INT , OUT empire_error INT , OUT planet_error INT ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE accid INT; astat TEXT; empid INT; plid INT; BEGIN -- Initialise return values account_error := 0; empire_error := 0; planet_error := 0; -- Find account SELECT INTO accid c.address_id FROM users.credentials c INNER JOIN users.addresses a ON a.id = c.address_id WHERE a.address = addr FOR UPDATE; IF NOT FOUND THEN PERFORM sys.write_log( 'AccountManagement' , 'WARNING'::log_level , 'account for "' || addr || '" not found' ); account_error := 1; RETURN; END IF; -- Get account status SELECT INTO astat status FROM users.accounts_view WHERE id = accid; IF astat NOT IN ('UNCONFIRMED' , 'REACTIVATING') THEN PERFORM users.write_log( accid , 'WARNING'::log_level , 'incorrect account status: ' || astat ); account_error := 1; ELSE -- Delete validation key DELETE FROM users.validation_keys WHERE credentials_id = accid AND token = vtoken; IF NOT FOUND THEN PERFORM users.write_log( accid , 'WARNING'::log_level , 'confirmation code "' || vtoken || '" not found' ); account_error := 2; END IF; END IF; -- Create / get empire empid := naming.goc_empire_name( accid , empname ); IF empid < 0 THEN empire_error := -empid; END IF; -- Get free planet, rename it plid := verse.get_random_planet( ); IF plid IS NULL THEN PERFORM users.write_log( accid , 'WARNING'::log_level , 'no free planets found!' ); planet_error := 2; ELSE planet_error := - naming.change_map_name( plid , accid , plname ); END IF; -- Activate account and create empire IF planet_error = 0 AND empire_error = 0 AND account_error = 0 THEN IF astat = 'REACTIVATING' THEN DELETE FROM users.inactive_accounts WHERE credentials_id = accid; END IF; INSERT INTO users.active_accounts (credentials_id, vacation_credits) VALUES ( accid , sys.get_constant( 'vacation.initial' ) ); PERFORM emp.create_empire( empid , plid , sys.get_constant( 'game.initialCash' ) ); PERFORM users.write_log( accid , 'INFO'::log_level , 'created empire #' || empid || ' ("' || empname || '") with initial planet #' || plid || ' ("' || plname || '")' ); END IF; END; $$ LANGUAGE plpgsql; -- -- Creates an inactive account (used by command line tools) -- -- Parameters: -- addr mail address -- lang selected language -- pmd5 MD5 hash of password -- psha1 SHA-1 hash of password -- -- Returns: -- err_code error code: -- 0 on success -- -1 if the address exists -- -2 if the language does not exist -- a_id the account's identifier -- CREATE OR REPLACE FUNCTION users.create_inactive_account ( addr TEXT , lang TEXT , pmd5 TEXT , psha1 TEXT , OUT err_code INT , OUT a_id INT) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE vkey TEXT; l_id INT; BEGIN -- Get language SELECT INTO l_id l.id FROM defs.languages l CROSS JOIN defs.strings s LEFT OUTER JOIN defs.translations t ON t.lang_id = l.id AND t.string_id = s.id WHERE l.language = lang GROUP BY l.id HAVING count( s.* ) = count( t.* ); IF NOT FOUND THEN err_code := -2; a_id := NULL; RETURN; END IF; -- Create address a_id := users.create_address( addr ); IF a_id IS NULL THEN err_code := -1; RETURN; END IF; -- Insert credentials INSERT INTO users.credentials (address_id, pass_md5, pass_sha1, credits, language_id) VALUES ( a_id , pmd5 , psha1 , floor( sys.get_constant( 'game.initialCredits' ) ) , l_id ); INSERT INTO users.inactive_accounts ( credentials_id , since , status ) VALUES ( a_id , now() - '1s'::INTERVAL , 'PROCESSED' ); err_code := 0; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.create_inactive_account(TEXT,TEXT,TEXT,TEXT) TO :dbuser; -- -- Sets an account's language -- -- Parameters: -- u_mail User address -- l_tid Language identifier -- CREATE OR REPLACE FUNCTION users.set_language( u_mail TEXT , l_tid TEXT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE l_id INT; BEGIN SELECT INTO l_id l.id FROM defs.languages l CROSS JOIN defs.strings s LEFT OUTER JOIN defs.translations t ON t.lang_id = l.id AND t.string_id = s.id WHERE l.language = l_tid GROUP BY l.id HAVING count( s.* ) = count( t.* ); IF NOT FOUND THEN RETURN; END IF; UPDATE users.credentials c SET language_id = l_id FROM users.addresses a WHERE c.address_id = a.id AND a.address = u_mail; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.set_language( TEXT , TEXT ) TO :dbuser; -- -- Sets an account's password -- -- Parameters: -- u_id Account identifier -- p_sha1 SHA1 hash of the new password -- p_md5 MD-5 hash of the new password -- -- Returns: -- success Whether the operation was successful -- CREATE OR REPLACE FUNCTION users.set_password( u_id INT , p_sha1 TEXT , p_md5 TEXT , OUT success BOOLEAN ) STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE amd5 TEXT; asha1 TEXT; BEGIN SELECT INTO amd5, asha1 admin.pass_md5 , admin.pass_sha1 FROM users.credentials creds LEFT OUTER JOIN admin.admin_credentials acreds ON acreds.credentials_id = creds.address_id LEFT OUTER JOIN admin.administrators admin ON admin.id = acreds.administrator_id WHERE creds.address_id = u_id FOR UPDATE OF creds; IF amd5 IS NOT NULL AND amd5 = p_md5 AND asha1 = p_sha1 THEN success := FALSE; ELSE UPDATE users.credentials SET pass_md5 = p_md5 , pass_sha1 = p_sha1 WHERE address_id = u_id; PERFORM users.write_log( u_id , 'INFO'::log_level , 'Password changed' ); success := TRUE; END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.set_password( INT , TEXT , TEXT ) TO :dbuser; -- -- Causes old password recovery requests to expire -- CREATE OR REPLACE FUNCTION users.expire_pwd_recovery_requests() RETURNS VOID STRICT VOLATILE SECURITY INVOKER AS $$ DELETE FROM users.pwd_recovery_requests WHERE created <= now() - ( floor( sys.get_constant('accounts.prrDelay') ) || 's' )::INTERVAL; $$ LANGUAGE SQL; -- -- Causes old address change requests to expire -- CREATE OR REPLACE FUNCTION users.expire_addr_change_requests() RETURNS VOID STRICT VOLATILE SECURITY INVOKER AS $$ DECLARE rec RECORD; BEGIN FOR rec IN SELECT * FROM users.address_change_requests WHERE created <= now() - ( floor( sys.get_constant('accounts.acrDelay') ) || 's' )::INTERVAL FOR UPDATE LOOP IF rec.address_id = rec.credentials_id THEN DELETE FROM users.address_change_requests WHERE credentials_id = rec.credentials_id; ELSE DELETE FROM users.addresses WHERE id = rec.address_id; END IF; END LOOP; END; $$ LANGUAGE plpgsql; -- -- Causes unconfirmed new accounts to be deleted and unconfirmed reactived accounts to be disabled -- CREATE OR REPLACE FUNCTION users.expire_validation_keys() RETURNS VOID STRICT VOLATILE SECURITY INVOKER AS $$ DECLARE rec RECORD; BEGIN FOR rec IN SELECT v.credentials_id AS id , ( ia.credentials_id IS NULL ) AS was_new FROM users.validation_keys v INNER JOIN users.credentials c ON c.address_id = v.credentials_id INNER JOIN users.addresses a ON c.address_id = a.id LEFT OUTER JOIN users.inactive_accounts ia ON ia.credentials_id = c.address_id WHERE v.created <= now() - ( floor( sys.get_constant('accounts.cacDelay') ) || 's' )::INTERVAL FOR UPDATE OF v , c , a LOOP IF rec.was_new THEN DELETE FROM users.credentials WHERE address_id = rec.id; DELETE FROM users.addresses WHERE id = rec.id; ELSE DELETE FROM users.validation_keys WHERE credentials_id = rec.id; END IF; END LOOP; END; $$ LANGUAGE plpgsql; -- -- Handle account requests expiry -- CREATE OR REPLACE FUNCTION users.expire_requests( ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ BEGIN PERFORM users.expire_pwd_recovery_requests(); PERFORM users.expire_addr_change_requests(); PERFORM users.expire_validation_keys(); END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.expire_requests() TO :dbuser; -- -- Disable quitting accounts -- CREATE TYPE quitting_account AS ( id INT , address TEXT , language TEXT ); CREATE OR REPLACE FUNCTION users.process_quit_requests( ) RETURNS SETOF quitting_account STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE addr quitting_account; rec RECORD; BEGIN UPDATE users.inactive_accounts SET status = 'PROCESSING' WHERE status = 'FUTURE' AND since <= now(); FOR rec IN SELECT ia.credentials_id AS account , e.name_id AS empire , ma.address AS address , l.language AS language FROM users.inactive_accounts ia INNER JOIN users.credentials c ON c.address_id = ia.credentials_id INNER JOIN defs.languages l ON l.id = c.language_id INNER JOIN users.active_accounts aa ON aa.credentials_id = ia.credentials_id INNER JOIN users.addresses ma ON ma.id = c.address_id INNER JOIN naming.empire_names en ON en.owner_id = ia.credentials_id INNER JOIN emp.empires e ON e.name_id = en.id WHERE ia.status = 'PROCESSING' FOR UPDATE OF ia , c , aa , ma , en , e LOOP PERFORM emp.delete_empire( rec.empire ); DELETE FROM users.active_accounts WHERE credentials_id = rec.account; UPDATE users.inactive_accounts SET status = 'PROCESSED' WHERE credentials_id = rec.account; addr.id = rec.account; addr.address = rec.address; addr.language := rec.language; RETURN NEXT addr; END LOOP; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.process_quit_requests( ) TO :dbuser; -- -- Sets an account in the QUITTING status -- -- Parameters: -- a_id Account identifier -- r_txt Reason -- CREATE OR REPLACE FUNCTION users.set_account_quit( a_id INT , r_txt TEXT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ BEGIN -- Verify and lock record PERFORM aa.credentials_id FROM users.active_accounts aa INNER JOIN users.credentials c ON aa.credentials_id = c.address_id LEFT OUTER JOIN users.inactive_accounts ia ON ia.credentials_id = c.address_id LEFT OUTER JOIN users.vacations v ON v.account_id = aa.credentials_id WHERE aa.credentials_id = a_id AND ia.credentials_id IS NULL AND v.account_id IS NULL FOR UPDATE OF aa , c; IF NOT FOUND THEN RETURN; END IF; -- Insert de-activation record INSERT INTO users.inactive_accounts ( credentials_id , status , since ) VALUES ( a_id , 'FUTURE' , now() + ( floor( sys.get_constant( 'accounts.quitDelay' ) ) || 's' )::INTERVAL ); IF r_txt <> '' THEN INSERT INTO users.reasons ( account_id , reason ) VALUES ( a_id , r_txt ); END IF; PERFORM users.write_log( a_id , 'INFO'::log_level , 'Quitting' ); END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.set_account_quit( INT , TEXT ) TO :dbuser; -- -- Prevents an account from being disabled -- -- Parameters: -- a_id Account identifier -- r_txt Reason -- CREATE OR REPLACE FUNCTION users.cancel_account_quit( a_id INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ BEGIN -- Verify and lock record PERFORM aa.credentials_id FROM users.active_accounts aa INNER JOIN users.credentials c ON aa.credentials_id = c.address_id INNER JOIN users.inactive_accounts ia ON ia.credentials_id = c.address_id LEFT OUTER JOIN users.bans b ON b.account_id = aa.credentials_id WHERE aa.credentials_id = a_id AND b.account_id IS NULL AND ia.status = 'FUTURE' FOR UPDATE OF aa , c , ia; IF NOT FOUND THEN RETURN; END IF; DELETE FROM users.inactive_accounts WHERE credentials_id = a_id; PERFORM users.write_log( a_id , 'INFO'::log_level , 'No longer quitting' ); END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.cancel_account_quit( INT ) TO :dbuser; -- -- Prepares an account for vacation mode -- -- Parameters: -- a_id Account identifier -- CREATE OR REPLACE FUNCTION users.set_vacation( a_id INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ BEGIN PERFORM aa.credentials_id FROM users.active_accounts aa INNER JOIN users.credentials c ON aa.credentials_id = c.address_id LEFT OUTER JOIN users.vacations v ON v.account_id = aa.credentials_id LEFT OUTER JOIN users.inactive_accounts ia ON ia.credentials_id = aa.credentials_id WHERE aa.credentials_id = a_id AND v.account_id IS NULL AND ia.credentials_id IS NULL AND aa.vacation_credits > 0 FOR UPDATE OF aa , c; IF NOT FOUND THEN RETURN; END IF; INSERT INTO users.vacations ( account_id , since , status ) VALUES ( a_id , now() + ( floor( sys.get_constant( 'vacation.delay' ) ) || 's' )::INTERVAL , 'FUTURE' ); PERFORM users.write_log( a_id , 'INFO'::log_level , 'Preparing to enter vacation mode' ); END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.set_vacation( INT ) TO :dbuser; -- -- Causes an account to exit vacation mode, or to avoid entering it -- -- Parameters: -- a_id Account identifier -- CREATE OR REPLACE FUNCTION users.leave_vacation( a_id INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE active BOOLEAN; e_id INT; BEGIN SELECT INTO active , e_id ( v.status = 'PROCESSED' ) , e.name_id FROM users.active_accounts aa INNER JOIN users.credentials c ON aa.credentials_id = c.address_id INNER JOIN users.vacations v ON v.account_id = aa.credentials_id INNER JOIN naming.empire_names en ON en.owner_id = v.account_id INNER JOIN emp.empires e ON e.name_id = en.id WHERE aa.credentials_id = a_id FOR UPDATE OF v , aa , c; IF NOT FOUND THEN RETURN; END IF; IF active THEN PERFORM emp.switch_enemies( e_id ); PERFORM users.write_log( a_id , 'INFO'::log_level , 'Left vacation mode' ); ELSE PERFORM users.write_log( a_id , 'INFO'::log_level , 'Cancelled vacation mode' ); END IF; DELETE FROM users.vacations WHERE account_id = a_id; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.leave_vacation( INT ) TO :dbuser; -- -- Manage vacation credits and activate / disable vacation mode -- CREATE OR REPLACE FUNCTION users.process_vacations( ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE a_id INT; e_id INT; BEGIN -- Increase vacation credits for accounts that are not quitting or on/entering vacation UPDATE users.active_accounts aa SET vacation_credits = aa.vacation_credits + 1 FROM users.credentials c LEFT OUTER JOIN users.vacations v ON v.account_id = c.address_id LEFT OUTER JOIN users.inactive_accounts ia ON ia.credentials_id = c.address_id WHERE aa.credentials_id = c.address_id AND v.account_id IS NULL AND ia.credentials_id IS NULL AND aa.vacation_credits < floor( sys.get_constant( 'vacation.max' ) ); -- Process accounts that should enter vacation mode FOR a_id , e_id IN SELECT v.account_id , e.name_id FROM users.vacations v INNER JOIN users.active_accounts aa ON aa.credentials_id = v.account_id INNER JOIN users.credentials c ON c.address_id = v.account_id INNER JOIN naming.empire_names n ON n.owner_id = v.account_id INNER JOIN emp.empires e ON e.name_id = n.id WHERE v.status = 'FUTURE' AND v.since <= now( ) FOR UPDATE OF v , aa , c , n , e LOOP UPDATE users.vacations SET status = 'PROCESSED' WHERE account_id = a_id; END LOOP; -- Decrease vacation credits UPDATE users.active_accounts aa SET vacation_credits = ( CASE WHEN aa.vacation_credits > floor( sys.get_constant( 'vacation.cost' ) ) THEN aa.vacation_credits - floor( sys.get_constant( 'vacation.cost' ) ) ELSE 0 END ) FROM users.vacations v WHERE aa.credentials_id = v.account_id AND v.status = 'PROCESSED'; -- Process accounts that should exit vacation mode FOR a_id , e_id IN SELECT v.account_id , e.name_id FROM users.vacations v INNER JOIN users.active_accounts aa ON aa.credentials_id = v.account_id INNER JOIN users.credentials c ON c.address_id = v.account_id INNER JOIN naming.empire_names n ON n.owner_id = v.account_id INNER JOIN emp.empires e ON e.name_id = n.id WHERE v.status = 'PROCESSED' AND aa.vacation_credits = 0 FOR UPDATE OF v , aa , c , n , e LOOP PERFORM users.write_log( a_id , 'INFO'::log_level , 'Out of vacation credits - leaving vacation mode' ); PERFORM users.sessions_terminate( users.sessions_login( a_id , 'N/A' , 'vac_end' , 'N/A' ) , 'MANUAL' ); DELETE FROM users.vacations WHERE account_id = a_id; PERFORM emp.switch_enemies( e_id ); END LOOP; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION users.process_vacations( ) TO :dbuser; -- -- Grants credits to an account -- -- Parameters: -- a_id Administrator identifier -- c_id Account identifier -- c_inc Credits to grant -- CREATE OR REPLACE FUNCTION admin.grant_user_credits( a_id INT , c_id INT , c_inc INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ BEGIN UPDATE users.credentials SET credits = credits + c_inc WHERE address_id = c_id; PERFORM admin.write_log( a_id , 'INFO'::log_level , 'Granted ' || c_inc || ' credit(s) to user #' || c_id ); END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION admin.grant_user_credits( INT , INT , INT ) TO :dbuser; -- -- View for mail address change requests -- CREATE VIEW users.mail_change_view AS SELECT r.credentials_id AS id , r.used , ( r.created + ( floor( sys.get_constant( 'accounts.acrDelay' ) ) || 's' )::INTERVAL ) AS expires , ( CASE WHEN r.used THEN NULL ELSE a.address END ) AS new_address FROM users.address_change_requests r INNER JOIN users.addresses a ON a.id = r.address_id; GRANT SELECT ON users.mail_change_view TO :dbuser;