-- LegacyWorlds Beta 6 -- PostgreSQL database scripts -- -- Alliance views and management functions -- -- Copyright(C) 2004-2010, DeepClone Development -- -------------------------------------------------------- -- -- Alliances public information -- CREATE VIEW emp.alliances_public AS SELECT a.id AS id , a.tag AS tag , a.name AS name , a.leader_id AS leader_id , n.name AS leader_name , count( p.* ) AS planets FROM emp.alliances a INNER JOIN naming.empire_names n ON n.id = a.leader_id LEFT OUTER JOIN emp.alliance_members am ON am.alliance_id = a.id AND NOT am.is_pending LEFT OUTER JOIN emp.planets p ON p.empire_id = am.empire_id GROUP BY a.id , a.tag , a.name , a.leader_id , n.name; GRANT SELECT ON emp.alliances_public TO :dbuser; -- -- Alliance members / pending requests -- CREATE VIEW emp.alliance_membership AS SELECT a.alliance_id AS alliance , a.empire_id AS id , n.name AS name , a.is_pending AS pending FROM emp.alliance_members a INNER JOIN naming.empire_names n ON n.id = a.empire_id ORDER BY n.name; GRANT SELECT ON emp.alliance_membership TO :dbuser; -- -- Alliance planets -- CREATE VIEW emp.alliance_planets AS SELECT a.alliance_id AS alliance , a.empire_id AS owner_id , en.name AS owner_name , s.x AS x , s.y AS y , p.orbit AS orbit , ep.planet_id AS planet_id , pn.name AS planet_name , ( bcs IS NOT NULL ) AS battle , bcs.defence , bcs.attack FROM emp.alliance_members a INNER JOIN naming.empire_names en ON en.id = a.empire_id INNER JOIN emp.planets ep ON ep.empire_id = a.empire_id INNER JOIN verse.planets p ON p.name_id = ep.planet_id INNER JOIN verse.systems s ON s.id = p.system_id INNER JOIN naming.map_names pn ON pn.id = ep.planet_id LEFT OUTER JOIN battles.current_status bcs ON bcs.location = p.name_id WHERE NOT a.is_pending ORDER BY en.name , s.x , s.y , p.orbit; GRANT SELECT ON emp.alliance_planets TO :dbuser; -- -- Creates an alliance -- -- Parameters: -- e_id Empire identifier -- a_tag Alliance tag -- a_name Alliance name -- -- Returns: -- a_id Alliance identifier (NULL on failure) -- CREATE OR REPLACE FUNCTION emp.create_alliance( e_id INT , a_tag TEXT , a_name TEXT , OUT a_id INT ) STRICT VOLATILE SECURITY DEFINER AS $$ BEGIN BEGIN INSERT INTO emp.alliances ( tag , name , leader_id ) VALUES ( a_tag , a_name , e_id ) RETURNING id INTO a_id; EXCEPTION WHEN unique_violation THEN a_id := NULL; RETURN; END; BEGIN INSERT INTO emp.alliance_members ( alliance_id , empire_id , is_pending ) VALUES ( a_id , e_id , FALSE ); EXCEPTION WHEN unique_violation THEN DELETE FROM emp.alliances WHERE id = a_id; a_id := NULL; RETURN; END; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION emp.create_alliance( INT , TEXT , TEXT ) TO :dbuser; -- -- Requests to join an alliance -- -- Parameters: -- e_id Empire identifier -- a_id Alliance identifier -- -- Returns: -- success Whether the operation was successful or not -- CREATE OR REPLACE FUNCTION emp.join_alliance( e_id INT , a_id INT , OUT success BOOLEAN ) STRICT VOLATILE SECURITY DEFINER AS $$ BEGIN INSERT INTO emp.alliance_members( empire_id , alliance_id ) VALUES ( e_id , a_id ); DELETE FROM emp.enemy_alliances WHERE empire_id = e_id AND alliance_id = a_id; PERFORM events.alliance_request_event( a_id , e_id ); PERFORM msgs.deliver_internal( ); success := TRUE; EXCEPTION WHEN unique_violation THEN success := FALSE; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION emp.join_alliance( INT , INT ) TO :dbuser; -- -- Removes an empire's pending alliance membership -- -- Parameters: -- e_id Empire identifier -- CREATE OR REPLACE FUNCTION emp.cancel_join( e_id INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DELETE FROM emp.alliance_members WHERE empire_id = $1 AND is_pending; $$ LANGUAGE SQL; GRANT EXECUTE ON FUNCTION emp.cancel_join( INT ) TO :dbuser; -- -- Leave an alliance -- -- Parameters: -- e_id Empire identifier -- CREATE OR REPLACE FUNCTION emp.leave_alliance( e_id INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE l_id INT; a_id INT; BEGIN SELECT INTO a_id , l_id a.id , a.leader_id FROM emp.alliance_members m INNER JOIN emp.alliances a ON a.id = m.alliance_id WHERE m.empire_id = e_id AND NOT m.is_pending FOR UPDATE; IF FOUND THEN IF l_id = e_id THEN PERFORM events.alliance_disband_event( a_id ); DELETE FROM emp.alliances WHERE id = a_id; ELSE DELETE FROM emp.alliance_members WHERE empire_id = e_id; PERFORM events.alliance_quit_event( a_id , e_id ); END IF; PERFORM msgs.deliver_internal( ); END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION emp.leave_alliance( INT ) TO :dbuser; -- -- Transfer alliance leadership -- -- Parameters: -- e_id Empire identifier of an alliance's leader -- to_id Empire identifier of the alliance member who is being made the new leader -- CREATE OR REPLACE FUNCTION emp.transfer_leadership( e_id INT , to_id INT ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE a_id INT; BEGIN SELECT INTO a_id a.id FROM emp.alliance_members m INNER JOIN emp.alliances a ON a.id = m.alliance_id AND a.leader_id = e_id WHERE m.empire_id = to_id AND NOT m.is_pending FOR UPDATE; IF FOUND THEN UPDATE emp.alliances SET leader_id = to_id WHERE id = a_id; PERFORM events.alliance_lchange_event( a_id , e_id ); PERFORM msgs.deliver_internal( ); END IF; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION emp.transfer_leadership( INT , INT ) TO :dbuser; -- -- Accept new members into an alliance -- -- Parameters: -- e_id Empire identifier -- r_ids Requests to accept -- CREATE OR REPLACE FUNCTION emp.accept_members( e_id INT , r_ids INT[] ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE a_id INT; re_id INT; BEGIN SELECT INTO a_id id FROM emp.alliances WHERE leader_id = e_id FOR UPDATE; IF NOT FOUND THEN RETURN; END IF; FOR re_id IN SELECT m.empire_id FROM emp.alliance_members m INNER JOIN unnest( r_ids ) rid ON m.empire_id = rid WHERE m.is_pending LOOP PERFORM events.alliance_response_event( a_id , re_id , TRUE ); END LOOP; PERFORM msgs.deliver_internal( ); UPDATE emp.alliance_members SET is_pending = FALSE WHERE alliance_id = a_id AND empire_id IN ( SELECT * FROM unnest( r_ids ) ); END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION emp.accept_members( INT , INT[] ) TO :dbuser; -- -- Reject membership requests -- -- Parameters: -- e_id Empire identifier -- r_ids Requests to reject -- CREATE OR REPLACE FUNCTION emp.reject_members( e_id INT , r_ids INT[] ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE a_id INT; re_id INT; BEGIN SELECT INTO a_id id FROM emp.alliances WHERE leader_id = e_id FOR UPDATE; IF NOT FOUND THEN RETURN; END IF; FOR re_id IN SELECT m.empire_id FROM emp.alliance_members m INNER JOIN unnest( r_ids ) rid ON m.empire_id = rid WHERE m.is_pending LOOP PERFORM events.alliance_response_event( a_id , re_id , FALSE ); END LOOP; PERFORM msgs.deliver_internal( ); DELETE FROM emp.alliance_members WHERE alliance_id = a_id AND is_pending AND empire_id IN ( SELECT * FROM unnest( r_ids ) ); END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION emp.reject_members( INT , INT[] ) TO :dbuser; -- -- Kick members from an alliance -- -- Parameters: -- e_id Empire identifier -- kick_ids Requests to reject -- CREATE OR REPLACE FUNCTION emp.kick_members( e_id INT , kick_ids INT[] ) RETURNS VOID STRICT VOLATILE SECURITY DEFINER AS $$ DECLARE a_id INT; k_id INT; BEGIN SELECT INTO a_id id FROM emp.alliances WHERE leader_id = e_id FOR UPDATE; IF NOT FOUND THEN RETURN; END IF; FOR k_id IN SELECT m.empire_id FROM emp.alliance_members m INNER JOIN unnest( kick_ids ) rid ON m.empire_id = rid WHERE NOT m.is_pending LOOP PERFORM events.alliance_kick_event( a_id , k_id ); END LOOP; PERFORM msgs.deliver_internal( ); DELETE FROM emp.alliance_members WHERE alliance_id = a_id AND NOT is_pending AND empire_id IN ( SELECT * FROM unnest( kick_ids ) ) AND empire_id <> e_id; END; $$ LANGUAGE plpgsql; GRANT EXECUTE ON FUNCTION emp.kick_members( INT , INT[] ) TO :dbuser;