package be.jeffcheasey88.peeratcode.repository; import java.sql.Connection; import java.sql.PreparedStatement; import java.sql.SQLException; public enum DatabaseQuery { // PUZZLES SPECIFIC_PUZZLE_QUERY( "SELECT p.*, np.origin, GROUP_CONCAT(t.name) AS tags FROM puzzles p LEFT JOIN nextPart np ON p.id_puzzle = np.next LEFT JOIN containsTags ct ON ct.fk_puzzle = p.id_puzzle LEFT JOIN tags t ON t.id_tag = ct.fk_tag WHERE p.id_puzzle = ? GROUP BY p.id_puzzle"), PUZZLES_IN_CHAPTER_QUERY( "SELECT p.*, GROUP_CONCAT(t.name) AS tags FROM puzzles p LEFT JOIN containsTags ct ON ct.fk_puzzle = p.id_puzzle LEFT JOIN tags t ON t.id_tag = ct.fk_tag WHERE fk_chapter = ? GROUP BY p.id_puzzle"), // CHAPTERS SPECIFIC_CHAPTER_QUERY("SELECT * FROM chapters WHERE id_chapter = ?"), CHAPTER_FROM_PUZZLE("SELECT c.*\r\n" + "FROM chapters c\r\n" + "JOIN puzzles p ON p.fk_chapter = c.id_chapter\r\n" + "WHERE p.id_puzzle = ?"), ALL_CHAPTERS_QUERY("SELECT * FROM chapters WHERE id_chapter > 0"), // GROUPS ALL_GROUPS("SELECT * FROM groups"), GET_GROUP_FOR_PLAYER("SELECT g.* FROM groups g JOIN containsGroups cg ON cg.fk_group = g.id_group WHERE cg.fk_player = ? AND g.fk_chapter = ?"), // AND g.fk_puzzle = ? GET_GROUP_ID_BY_DATA("SELECT id_group FROM groups WHERE name = ? AND (fk_chapter = ?)"), // OR fk_puzzle = ? INSERT_GROUP("INSERT INTO groups (name, fk_chapter) VALUES (?,?)"), INSERT_PLAYER_IN_GROUP("INSERT INTO containsGroups (fk_player, fk_group) VALUES (?,?)"), LEAVE_GROUP("DELETE FROM containsGroups WHERE fk_player = ? AND fk_group = ?"), // LEADERBOARD ALL_PLAYERS_FOR_LEADERBOARD( "select p.*, scores.*, g.* from players p ,(SELECT fk_player, SUM(c.score) AS score, COUNT(c.id_completion) AS completions, SUM(c.tries) AS tries, rank() over(ORDER BY score DESC) AS rank FROM completions c GROUP BY c.fk_player) AS scores LEFT JOIN containsGroups cg ON scores.fk_player = cg.fk_player LEFT JOIN groups g ON cg.fk_group = g.id_group WHERE p.id_player = scores.fk_player ORDER BY g.fk_chapter"), ALL_GROUP_FOR_CHAPTER_LEADERBOARD( "SELECT g.*, pl.pseudo, co.score, co.tries FROM groups g LEFT JOIN containsGroups cg ON g.id_group = cg.fk_group LEFT JOIN players pl ON cg.fk_player = pl.id_player LEFT JOIN completions co ON pl.id_player = co.fk_player WHERE cg.fk_player IS NOT NULL AND fk_chapter = ? AND (co.fk_puzzle IN (SELECT id_puzzle FROM puzzles puz WHERE puz.fk_chapter = g.fk_chapter) OR co.score IS NULL);"), // REGISTER CHECK_PSEUDO_AVAILABLE_QUERY("SELECT * FROM players WHERE pseudo = ?"), CHECK_EMAIL_AVAILABLE_QUERY("SELECT * FROM players WHERE email = ?"), REGISTER_QUERY( "INSERT INTO players (pseudo, email, passwd, firstname, lastname, description, avatar) VALUES (?, ?, ?, ?, ?, ?, ?)"), REGISTER_PLAYER_IN_EXISTING_GROUP( "INSERT INTO containsGroups (fk_player, fk_group) VALUES (?, (SELECT id_group FROM groups WHERE name = ?));"), // LOGIN CHECK_PASSWORD("SELECT id_player, passwd FROM players WHERE pseudo=?"), // COMPLETIONS GET_COMPLETION( "SELECT * FROM completions WHERE fk_puzzle = ? AND fk_player = ?"), GET_COMPLETION_GROUP("SELECT c.*\r\n" + "FROM completions c\r\n" + "JOIN containsGroups cG on c.fk_player = cG.fk_player\r\n" + "JOIN containsGroups cGs on cGs.fk_group = cG.fk_group\r\n" + "JOIN groups g on cG.fk_group = g.id_group\r\n" + "JOIN puzzles p on p.id_puzzle = c.fk_puzzle\r\n" + "WHERE cGs.fk_player = ? AND p.id_puzzle = ?"), INSERT_COMPLETION( "INSERT INTO completions (fk_puzzle, fk_player, tries, code, fileName, score) values (?, ?, ?, ?, ?, ?)"), UPDATE_COMPLETION( "UPDATE completions SET tries = ?, score = ?, fk_player = ? WHERE fk_puzzle = ? AND fk_player = ?"), SCORE("SELECT score FROM completions WHERE fk_player = ? AND fk_puzzle = ?"), SCORE_GROUP("SELECT c.score\r\n" + "FROM completions c\r\n" + "JOIN containsGroups cG on c.fk_player = cG.fk_player\r\n" + "JOIN containsGroups cGs on cGs.fk_group = cG.fk_group\r\n" + "JOIN groups g on cG.fk_group = g.id_group\r\n" + "JOIN puzzles p on p.id_puzzle = c.fk_puzzle\r\n" + "WHERE cGs.fk_player = ? AND p.id_puzzle = ?"), // PLAYERS GET_PLAYER_SIMPLE("SELECT pseudo, email, firstname, lastname, description FROM players WHERE id_player = ?"), GET_PLAYER_DETAILS("SELECT p.*, g.*\r\n" + "FROM players p\r\n" + "LEFT OUTER JOIN containsGroups cg ON p.id_player = cg.fk_player\r\n" + "LEFT OUTER JOIN groups g ON cg.fk_group = g.id_group\r\n" + "LEFT OUTER JOIN completions c on p.id_player = c.fk_player\r\n" + "WHERE "), GET_PLAYER_DETAILS_BY_ID(GET_PLAYER_DETAILS, " p.id_player = ? GROUP BY g.name ORDER BY g.fk_chapter, g.fk_puzzle;"), GET_PLAYER_DETAILS_BY_PSEUDO(GET_PLAYER_DETAILS, "p.pseudo = ? GROUP BY g.name ORDER BY g.fk_chapter, g.fk_puzzle;"), GET_PLAYER_COMPLETIONS("select c.*, p.name from completions c left join puzzles p on c.fk_puzzle = p.id_puzzle where fk_player = ?;"), GET_PLAYER_RANK("SELECT * FROM (SELECT fk_player, RANK() OVER(ORDER BY SUM(score) DESC) rank FROM completions c LEFT JOIN players p ON p.id_player = c.fk_player GROUP BY fk_player ORDER BY rank) AS ranks WHERE ranks.fk_player = ?;"), // BADGES GET_BADGE("SELECT * FROM badges WHERE id_badge = ?"), GET_BADGES_OF_PLAYER( "SELECT * FROM badges b LEFT JOIN containsBadges cb ON cb.fk_badge = b.id_badge WHERE cb.fk_player = ?"), //TRIGGER FIRST_TRY("CREATE OR REPLACE TRIGGER FirstTry\r\n" + "AFTER INSERT\r\n" + " ON completions FOR EACH ROW\r\n" + "BEGIN\r\n" + " DECLARE badge INT;\r\n" + " DECLARE contain INT;\r\n" + " \r\n" + " SELECT id_badge\r\n" + " INTO @badge\r\n" + " FROM badges\r\n" + " WHERE name = 'FirstTry';\r\n" + " \r\n" + " IF @badge is not null THEN\r\n" + " \r\n" + " SELECT count(*)\r\n" + " INTO @contain\r\n" + " FROM containsBadges\r\n" + " WHERE fk_badge = @badge AND fk_player = NEW.fk_player;\r\n" + " \r\n" + " IF (@contain = 0) THEN\r\n" + " INSERT INTO containsBadges(fk_player, fk_badge) VALUES (NEW.fk_player, @badge);\r\n" + " END IF;\r\n" + " END IF;\r\n" + "END;"), EventParticipation("CREATE OR REPLACE TRIGGER EventParticipation\r\n" + "AFTER INSERT\r\n" + " ON completions FOR EACH ROW\r\n" + "BEGIN\r\n" + " DECLARE badge INT;\r\n" + " DECLARE endDate datetime;\r\n" + " DECLARE player INT;\r\n" + " DECLARE contain INT;\r\n" + "\r\n" + " SELECT id_badge\r\n" + " INTO badge\r\n" + " FROM badges\r\n" + " WHERE name = 'EventParticipation';\r\n" + "\r\n" + " IF @badge is not null THEN\r\n" + "\r\n" + " SELECT c.end_date, i.fk_player\r\n" + " INTO endDate, player\r\n" + " FROM inserted i\r\n" + " JOIN puzzles p ON i.fk_puzzle = p.id_puzzle\r\n" + " JOIN chapters c on p.fk_chapter = c.id_chapter;\r\n" + "\r\n" + " IF @endDate is not null THEN\r\n" + "\r\n" + " SELECT count(*)\r\n" + " INTO contain\r\n" + " FROM containsBadges\r\n" + " WHERE fk_badge = badge AND fk_player = player;\r\n" + "\r\n" + " IF (@contain = 0) THEN\r\n" + " INSERT INTO containsBadges(fk_player, fk_badge) VALUES (@player, @badge);\r\n" + " END IF;\r\n" + " END IF;\r\n" + " END IF;\r\n" + "END;"); private String request; DatabaseQuery(DatabaseQuery parent, String request) { this.request = parent.request + request; } DatabaseQuery(String request) { this.request = request; } public PreparedStatement prepare(Connection con) throws SQLException { return con.prepareStatement(this.request); } @Override public String toString() { return this.request; } } /* * SELECT p.*, scores.score, scores.completions, scores.tries, scores.rank, g.* FROM players p, (SELECT fk_player, SUM(c.score) AS score, COUNT(c.id_completion) AS completions, SUM(c.tries) AS tries, rank() over(ORDER BY score DESC) AS rank FROM completions c GROUP BY c.fk_player) AS scores LEFT OUTER JOIN containsGroups cg ON scores.fk_player = cg.fk_player LEFT OUTER JOIN groups g ON cg.fk_group = g.id_group WHERE p.id_player = scores.fk_player AND "), * */ /* TRIGGER PLACE * CREATE OR REPLACE TRIGGER FirstTry AFTER INSERT ON completions FOR EACH ROW BEGIN DECLARE badge INT; DECLARE contain INT; SELECT id_badge INTO @badge FROM badges WHERE name = 'FirstTry'; IF @badge is not null THEN SELECT count(*) INTO @contain FROM containsBadges WHERE fk_badge = @badge AND fk_player = NEW.fk_player; IF (@contain = 0) THEN IF (NEW.score >= 0 AND NEW.tries < 2) THEN INSERT INTO containsBadges(fk_player, fk_badge) VALUES (NEW.fk_player, @badge); END IF; END IF; END IF; END; CREATE OR REPLACE TRIGGER EventParticipation AFTER INSERT ON completions FOR EACH ROW BEGIN DECLARE badge INT; DECLARE endDate datetime; DECLARE player INT; DECLARE contain INT; SELECT id_badge INTO badge FROM badges WHERE name = 'EventParticipation'; IF @badge is not null THEN SELECT c.end_date, i.fk_player INTO endDate, player FROM inserted i JOIN puzzles p ON i.fk_puzzle = p.id_puzzle JOIN chapters c on p.fk_chapter = c.id_chapter; IF @endDate is not null THEN SELECT count(*) INTO contain FROM containsBadges WHERE fk_badge = badge AND fk_player = player; IF (@contain = 0) THEN INSERT INTO containsBadges(fk_player, fk_badge) VALUES (@player, @badge); END IF; END IF; END IF; END; * */