diff --git a/database/psn100.sql b/database/psn100.sql index a631ecf..c8bb373 100644 --- a/database/psn100.sql +++ b/database/psn100.sql @@ -1,11 +1,11 @@ -- phpMyAdmin SQL Dump --- version 5.2.1 +-- version 6.0.0-dev+20250122.b28b32e424 -- https://www.phpmyadmin.net/ -- -- Host: localhost --- Generation Time: May 21, 2024 at 07:48 AM --- Server version: 8.0.37 --- PHP Version: 8.3.6 +-- Generation Time: Feb 17, 2025 at 04:17 PM +-- Server version: 8.0.41 +-- PHP Version: 8.4.3 SET SQL_MODE = "NO_AUTO_VALUE_ON_ZERO"; START TRANSACTION; @@ -22,7 +22,7 @@ SET time_zone = "+00:00"; -- CREATE TABLE `log` ( - `id` int NOT NULL, + `id` bigint UNSIGNED NOT NULL, `time` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP, `message` text CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; @@ -49,13 +49,9 @@ CREATE TABLE `player` ( `progress` tinyint UNSIGNED NOT NULL DEFAULT '0', `points` mediumint UNSIGNED NOT NULL DEFAULT '0', `rarity_points` int UNSIGNED NOT NULL DEFAULT '0', - `rank` mediumint UNSIGNED NOT NULL DEFAULT '16777215', `rank_last_week` mediumint UNSIGNED NOT NULL DEFAULT '0', - `rarity_rank` mediumint UNSIGNED NOT NULL DEFAULT '16777215', `rarity_rank_last_week` mediumint UNSIGNED NOT NULL DEFAULT '0', - `rank_country` mediumint UNSIGNED NOT NULL DEFAULT '0', `rank_country_last_week` mediumint UNSIGNED NOT NULL DEFAULT '0', - `rarity_rank_country` mediumint UNSIGNED NOT NULL DEFAULT '0', `rarity_rank_country_last_week` mediumint UNSIGNED NOT NULL DEFAULT '0', `common` mediumint UNSIGNED NOT NULL DEFAULT '0', `uncommon` mediumint UNSIGNED NOT NULL DEFAULT '0', @@ -66,23 +62,16 @@ CREATE TABLE `player` ( `trophy_count_npwr` mediumint UNSIGNED NOT NULL DEFAULT '0' ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; +-- -------------------------------------------------------- + -- --- Triggers `player` +-- Table structure for table `player_extra` -- -DELIMITER $$ -CREATE TRIGGER `after_update_player` AFTER UPDATE ON `player` FOR EACH ROW BEGIN -IF OLD.status = 0 AND NEW.status != 0 AND OLD.rank <= 50000 THEN -UPDATE `trophy_title` JOIN `trophy_title_player` USING (`np_communication_id`) SET `owners` = `owners` - 1, `owners_completed` = IF(progress = 100, `owners_completed` - 1, `owners_completed`) WHERE `account_id` = NEW.account_id; -ELSEIF OLD.status = 0 AND NEW.status = 0 AND OLD.rank <= 50000 AND NEW.rank > 50000 THEN -UPDATE `trophy_title` JOIN `trophy_title_player` USING (`np_communication_id`) SET `owners` = `owners` - 1, `owners_completed` = IF(progress = 100, `owners_completed` - 1, `owners_completed`) WHERE `account_id` = NEW.account_id; -ELSEIF OLD.status = 0 AND NEW.status = 0 AND OLD.rank > 50000 AND NEW.rank <= 50000 THEN -UPDATE `trophy_title` JOIN `trophy_title_player` USING (`np_communication_id`) SET `owners` = `owners` + 1, `owners_completed` = IF(progress = 100, `owners_completed` + 1, `owners_completed`) WHERE `account_id` = NEW.account_id; -ELSEIF OLD.status != 0 AND NEW.status = 0 AND NEW.rank <= 50000 THEN -UPDATE `trophy_title` JOIN `trophy_title_player` USING (`np_communication_id`) SET `owners` = `owners` + 1, `owners_completed` = IF(progress = 100, `owners_completed` + 1, `owners_completed`) WHERE `account_id` = NEW.account_id; -END IF; -END -$$ -DELIMITER ; + +CREATE TABLE `player_extra` ( + `account_id` bigint UNSIGNED NOT NULL, + `rank` mediumint UNSIGNED NOT NULL +) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- -------------------------------------------------------- @@ -104,7 +93,7 @@ CREATE TABLE `player_queue` ( -- CREATE TABLE `player_report` ( - `report_id` int UNSIGNED NOT NULL, + `report_id` bigint UNSIGNED NOT NULL, `account_id` bigint UNSIGNED NOT NULL, `ip_address` varchar(45) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL, `explanation` varchar(256) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL @@ -117,7 +106,7 @@ CREATE TABLE `player_report` ( -- CREATE TABLE `psn100_avatars` ( - `avatar_id` int UNSIGNED NOT NULL, + `avatar_id` bigint UNSIGNED NOT NULL, `size` varchar(2) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL, `avatar_url` text CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL, `md5_hash` varchar(32) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL, @@ -131,7 +120,7 @@ CREATE TABLE `psn100_avatars` ( -- CREATE TABLE `psn100_change` ( - `id` int NOT NULL, + `id` bigint UNSIGNED NOT NULL, `time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP, `change_type` enum('GAME_VERSION','GAME_CLONE','GAME_MERGE','GAME_UPDATE','GAME_DELISTED','GAME_OBSOLETE','GAME_DELISTED_AND_OBSOLETE','GAME_NORMAL','GAME_COPY','GAME_RESET','GAME_DELETE','GAME_RESCAN','GAME_UNOBTAINABLE','GAME_OBTAINABLE') CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL, `param_1` int NOT NULL, @@ -146,10 +135,11 @@ CREATE TABLE `psn100_change` ( -- CREATE TABLE `setting` ( - `id` int UNSIGNED NOT NULL, + `id` bigint UNSIGNED NOT NULL, `refresh_token` varchar(36) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL, `npsso` varchar(64) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL, - `scanning` varchar(16) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL + `scanning` varchar(16) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL, + `scan_start` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; -- -------------------------------------------------------- @@ -159,7 +149,7 @@ CREATE TABLE `setting` ( -- CREATE TABLE `trophy` ( - `id` int UNSIGNED NOT NULL, + `id` bigint UNSIGNED NOT NULL, `np_communication_id` varchar(12) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL, `group_id` varchar(7) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL, `order_id` smallint UNSIGNED NOT NULL, @@ -221,7 +211,7 @@ DELIMITER ; -- CREATE TABLE `trophy_group` ( - `id` int NOT NULL, + `id` bigint UNSIGNED NOT NULL, `np_communication_id` varchar(12) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL, `group_id` varchar(7) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL, `name` text CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL, @@ -272,7 +262,7 @@ CREATE TABLE `trophy_merge` ( -- CREATE TABLE `trophy_title` ( - `id` int UNSIGNED NOT NULL, + `id` bigint UNSIGNED NOT NULL, `np_communication_id` varchar(12) CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL, `name` text CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL, `detail` text CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci NOT NULL, @@ -295,18 +285,6 @@ CREATE TABLE `trophy_title` ( `rarity_points` int UNSIGNED NOT NULL DEFAULT '0' ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; --- --- Triggers `trophy_title` --- -DELIMITER $$ -CREATE TRIGGER `before_update_trophy_title` BEFORE UPDATE ON `trophy_title` FOR EACH ROW BEGIN -IF OLD.owners != NEW.owners OR OLD.owners_completed != NEW.owners_completed THEN -SET NEW.difficulty = IF(NEW.owners = 0, 0, (NEW.owners_completed / NEW.owners) * 100); -END IF; -END -$$ -DELIMITER ; - -- -------------------------------------------------------- -- @@ -336,36 +314,6 @@ CREATE TABLE `trophy_title_player` ( `temp_legendary` smallint UNSIGNED NOT NULL DEFAULT '0' ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci; --- --- Triggers `trophy_title_player` --- -DELIMITER $$ -CREATE TRIGGER `after_insert_trophy_title_player` AFTER INSERT ON `trophy_title_player` FOR EACH ROW BEGIN -DECLARE player_ok INT; -SET player_ok = (SELECT COUNT(1) FROM `player` WHERE `account_id` = NEW.account_id AND `status` = 0 AND `rank` <= 50000); -IF player_ok = 1 THEN -IF NEW.progress = 100 THEN -UPDATE `trophy_title` SET `owners` = `owners` + 1, `owners_completed` = `owners_completed` + 1 WHERE `np_communication_id` = NEW.np_communication_id; -ELSE -UPDATE `trophy_title` SET `owners` = `owners` + 1 WHERE `np_communication_id` = NEW.np_communication_id; -END IF; -END IF; -END -$$ -DELIMITER ; -DELIMITER $$ -CREATE TRIGGER `after_update_trophy_title_player` AFTER UPDATE ON `trophy_title_player` FOR EACH ROW BEGIN -DECLARE player_ok INT; -SET player_ok = (SELECT COUNT(1) FROM `player` WHERE `account_id` = NEW.account_id AND `status` = 0 AND `rank` <= 50000); -IF player_ok = 1 AND OLD.progress != 100 AND NEW.progress = 100 THEN -UPDATE `trophy_title` SET `owners_completed` = `owners_completed` + 1 WHERE `np_communication_id` = NEW.np_communication_id; -ELSEIF player_ok = 1 AND OLD.progress = 100 AND NEW.progress != 100 THEN -UPDATE `trophy_title` SET `owners_completed` = `owners_completed` - 1 WHERE `np_communication_id` = NEW.np_communication_id; -END IF; -END -$$ -DELIMITER ; - -- -- Indexes for dumped tables -- @@ -382,16 +330,23 @@ ALTER TABLE `log` ALTER TABLE `player` ADD PRIMARY KEY (`account_id`), ADD UNIQUE KEY `u_online_id` (`online_id`), - ADD KEY `idx_rarity_rank` (`rarity_rank`), ADD KEY `idx_avatar_url` (`avatar_url`), - ADD KEY `idx_status_rank_aid` (`status`,`rank`,`account_id`); + ADD KEY `idx_last_updated_date` (`last_updated_date`), + ADD KEY `idx_status` (`status`) USING BTREE; + +-- +-- Indexes for table `player_extra` +-- +ALTER TABLE `player_extra` + ADD UNIQUE KEY `idx_account_id` (`account_id`); -- -- Indexes for table `player_queue` -- ALTER TABLE `player_queue` ADD UNIQUE KEY `u_online_id` (`online_id`), - ADD KEY `idx_time_oid` (`request_time`,`online_id`); + ADD KEY `idx_time_oid` (`request_time`,`online_id`), + ADD KEY `idx_ip_address` (`ip_address`); -- -- Indexes for table `player_report` @@ -404,7 +359,8 @@ ALTER TABLE `player_report` -- Indexes for table `psn100_avatars` -- ALTER TABLE `psn100_avatars` - ADD PRIMARY KEY (`avatar_id`); + ADD PRIMARY KEY (`avatar_id`), + ADD KEY `idx_avatar_url` (`avatar_url`(760)); -- -- Indexes for table `psn100_change` @@ -465,7 +421,9 @@ ALTER TABLE `trophy_title` ADD PRIMARY KEY (`id`), ADD UNIQUE KEY `u_np_communication_id` (`np_communication_id`), ADD KEY `idx_npcid_status` (`np_communication_id`,`status`), - ADD KEY `idx_status` (`status`); + ADD KEY `idx_status` (`status`), + ADD KEY `idx_parent_np_communication_id` (`parent_np_communication_id`), + ADD KEY `idx_psnprofiles_id` (`psnprofiles_id`); ALTER TABLE `trophy_title` ADD FULLTEXT KEY `idx_name` (`name`); -- @@ -485,47 +443,47 @@ ALTER TABLE `trophy_title_player` -- AUTO_INCREMENT for table `log` -- ALTER TABLE `log` - MODIFY `id` int NOT NULL AUTO_INCREMENT; + MODIFY `id` bigint UNSIGNED NOT NULL AUTO_INCREMENT, AUTO_INCREMENT=1564469; -- -- AUTO_INCREMENT for table `player_report` -- ALTER TABLE `player_report` - MODIFY `report_id` int UNSIGNED NOT NULL AUTO_INCREMENT; + MODIFY `report_id` bigint UNSIGNED NOT NULL AUTO_INCREMENT, AUTO_INCREMENT=22; -- -- AUTO_INCREMENT for table `psn100_avatars` -- ALTER TABLE `psn100_avatars` - MODIFY `avatar_id` int UNSIGNED NOT NULL AUTO_INCREMENT; + MODIFY `avatar_id` bigint UNSIGNED NOT NULL AUTO_INCREMENT, AUTO_INCREMENT=24036; -- -- AUTO_INCREMENT for table `psn100_change` -- ALTER TABLE `psn100_change` - MODIFY `id` int NOT NULL AUTO_INCREMENT; + MODIFY `id` bigint UNSIGNED NOT NULL AUTO_INCREMENT, AUTO_INCREMENT=29811; -- -- AUTO_INCREMENT for table `setting` -- ALTER TABLE `setting` - MODIFY `id` int UNSIGNED NOT NULL AUTO_INCREMENT; + MODIFY `id` bigint UNSIGNED NOT NULL AUTO_INCREMENT, AUTO_INCREMENT=21; -- -- AUTO_INCREMENT for table `trophy` -- ALTER TABLE `trophy` - MODIFY `id` int UNSIGNED NOT NULL AUTO_INCREMENT; + MODIFY `id` bigint UNSIGNED NOT NULL AUTO_INCREMENT, AUTO_INCREMENT=1677525; -- -- AUTO_INCREMENT for table `trophy_group` -- ALTER TABLE `trophy_group` - MODIFY `id` int NOT NULL AUTO_INCREMENT; + MODIFY `id` bigint UNSIGNED NOT NULL AUTO_INCREMENT, AUTO_INCREMENT=72485; -- -- AUTO_INCREMENT for table `trophy_title` -- ALTER TABLE `trophy_title` - MODIFY `id` int UNSIGNED NOT NULL AUTO_INCREMENT; + MODIFY `id` bigint UNSIGNED NOT NULL AUTO_INCREMENT, AUTO_INCREMENT=52403; COMMIT; diff --git a/wwwroot/about.php b/wwwroot/about.php index 11e6b0b..1c74226 100644 --- a/wwwroot/about.php +++ b/wwwroot/about.php @@ -86,19 +86,20 @@ prepare("SELECT - online_id, - country, - avatar_url, - last_updated_date, - `level`, - progress, - `rank`, - rank_last_week, - `status` + p.online_id, + p.country, + p.avatar_url, + p.last_updated_date, + p.level, + p.progress, + p.rank_last_week, + p.status, + r.ranking FROM - `player` + `player` p + LEFT JOIN (SELECT `online_id`, RANK() OVER (ORDER BY `points` DESC, `platinum` DESC, `gold` DESC, `silver` DESC) `ranking` FROM `player` WHERE `status` = 0) r ON r.online_id = p.online_id ORDER BY - last_updated_date + p.last_updated_date DESC LIMIT 10"); $query->execute(); @@ -110,7 +111,7 @@ if ($player["status"] != 0) { $rank = "N/A"; } else { - $rank = $player["rank"]; + $rank = $player["ranking"]; } $rank .= "
"; if ($player["status"] == 1) { @@ -124,7 +125,7 @@ } elseif ($player["rank_last_week"] == 0 || $player["rank_last_week"] == 16777215) { $rank .= "(New!)"; } else { - $delta = $player["rank_last_week"] - $player["rank"]; + $delta = $player["rank_last_week"] - $player["ranking"]; if ($delta < 0) { $rank .= "(". $delta .")"; diff --git a/wwwroot/admin/cheater.php b/wwwroot/admin/cheater.php index 812701f..3d207cf 100644 --- a/wwwroot/admin/cheater.php +++ b/wwwroot/admin/cheater.php @@ -5,7 +5,7 @@ $onlineId = $_POST["player"]; $database->beginTransaction(); - $query = $database->prepare("UPDATE player SET status = 1, `rank` = 0, rank_last_week = 0, rarity_rank = 0, rarity_rank_last_week = 0, rank_country = 0, rank_country_last_week = 0, rarity_rank_country = 0, rarity_rank_country_last_week = 0 WHERE online_id = :online_id"); + $query = $database->prepare("UPDATE player SET `status` = 1, rank_last_week = 0, rarity_rank_last_week = 0, rank_country_last_week = 0, rarity_rank_country_last_week = 0 WHERE online_id = :online_id"); $query->bindParam(":online_id", $onlineId, PDO::PARAM_STR); $query->execute(); $database->commit(); diff --git a/wwwroot/avatars.php b/wwwroot/avatars.php index 16c3ec2..41a2c0a 100644 --- a/wwwroot/avatars.php +++ b/wwwroot/avatars.php @@ -2,7 +2,9 @@ $title = "Avatars ~ PSN 100%"; require_once("header.php"); -$query = $database->prepare("SELECT COUNT(DISTINCT avatar_url) FROM player p WHERE p.status = 0 AND (p.rank <= 50000 OR p.rarity_rank <= 50000)"); +$query = $database->prepare("SELECT COUNT(DISTINCT avatar_url) FROM player p + LEFT JOIN (SELECT account_id, RANK() OVER (ORDER BY `points` DESC, `platinum` DESC, `gold` DESC, `silver` DESC) `ranking`, RANK() OVER (ORDER BY `rarity_points` DESC) `rarity_ranking` FROM player WHERE `status` = 0) r ON p.account_id = r.account_id + WHERE p.status = 0 AND (r.ranking <= 50000 OR r.rarity_ranking <= 50000)"); $query->execute(); $total_pages = $query->fetchColumn(); @@ -23,8 +25,9 @@ $query = $database->prepare("SELECT Count(*) AS count, avatar_url FROM player p + LEFT JOIN (SELECT account_id, RANK() OVER (ORDER BY `points` DESC, `platinum` DESC, `gold` DESC, `silver` DESC) `ranking`, RANK() OVER (ORDER BY `rarity_points` DESC) `rarity_ranking` FROM player WHERE `status` = 0) r ON p.account_id = r.account_id WHERE p.status = 0 - AND (p.rank <= 50000 OR p.rarity_rank <= 50000) + AND (r.ranking <= 50000 OR r.rarity_ranking <= 50000) GROUP BY avatar_url ORDER BY count DESC, avatar_url diff --git a/wwwroot/cron/30th_minute.php b/wwwroot/cron/30th_minute.php index b7216de..e82608b 100644 --- a/wwwroot/cron/30th_minute.php +++ b/wwwroot/cron/30th_minute.php @@ -357,135 +357,141 @@ function Psn100Log($message) { } } - // Get our queue. - // #1 - Users added from the front page, ordered by time entered - // #2 - Top 100 players who haven't been updated within a day, ordered by the oldest one. - // #3 - Top 1000 players or +/- 250 players who are about to drop out of top 50k who haven't been updated within a week, ordered by the oldest one. - // #4 - Top 10000 players who haven't been updated within a month, ordered by the oldest one. - // #5 - Top 50000 players who haven't been updated within six months, ordered by the oldest one. - // #6 - Users added by Ragowit when site was created to populate the site, ordered by name (will be removed once done) - // #7 - Oldest scanned player who is not tagged as a cheater - $query = $database->prepare("SELECT - online_id, - account_id - FROM - ( - SELECT - 1 AS tier, - pq.online_id, - pq.request_time, - p.account_id - FROM - player_queue pq - LEFT JOIN player p ON p.online_id = pq.online_id - WHERE - pq.request_time < '2030-12-25 00:00:00' - UNION ALL - SELECT - 2 AS tier, - online_id, - last_updated_date, - account_id - FROM - player - WHERE - ( - `rank` <= 100 - OR rarity_rank <= 100 - ) - AND last_updated_date < NOW() - INTERVAL 1 HOUR - AND `status` = 0 - UNION ALL - SELECT - 3 AS tier, - online_id, - last_updated_date, - account_id - FROM - player - WHERE - ( - `rank` <= 1000 - OR rarity_rank <= 1000 - OR ( - `rank` >= 49750 - AND `rank` <= 50250 + try { + // Get our queue. + // #1 - Users added from the front page, ordered by time entered + // #2 - Top 100 players who haven't been updated within a day, ordered by the oldest one. + // #3 - Top 1000 players or +/- 250 players who are about to drop out of top 50k who haven't been updated within a week, ordered by the oldest one. + // #4 - Top 10000 players who haven't been updated within a month, ordered by the oldest one. + // #5 - Top 50000 players who haven't been updated within six months, ordered by the oldest one. + // #6 - Users added by Ragowit when site was created to populate the site, ordered by name (will be removed once done) + // #7 - Oldest scanned player who is not tagged as a cheater + $query = $database->prepare("SELECT + online_id, + account_id + FROM + ( + SELECT + 1 AS tier, + pq.online_id, + pq.request_time, + p.account_id + FROM + player_queue pq + LEFT JOIN player p ON p.online_id = pq.online_id + WHERE + pq.request_time < '2030-12-25 00:00:00' + UNION ALL + SELECT + 2 AS tier, + online_id, + last_updated_date, + account_id + FROM + player + LEFT JOIN (SELECT account_id, RANK() OVER (ORDER BY `points` DESC, `platinum` DESC, `gold` DESC, `silver` DESC) `ranking`, RANK() OVER (ORDER BY `rarity_points` DESC) `rarity_ranking` FROM `player` WHERE `status` = 0) r USING (account_id) + WHERE + ( + r.ranking <= 100 + OR r.rarity_ranking <= 100 ) - OR ( - `rarity_rank` >= 49750 - AND `rarity_rank` <= 50250 + AND last_updated_date < NOW() - INTERVAL 1 HOUR + UNION ALL + SELECT + 3 AS tier, + online_id, + last_updated_date, + account_id + FROM + player + LEFT JOIN (SELECT account_id, RANK() OVER (ORDER BY `points` DESC, `platinum` DESC, `gold` DESC, `silver` DESC) `ranking`, RANK() OVER (ORDER BY `rarity_points` DESC) `rarity_ranking` FROM `player` WHERE `status` = 0) r USING (account_id) + WHERE + ( + r.ranking <= 1000 + OR r.rarity_ranking <= 1000 + OR ( + r.ranking >= 49750 + AND r.ranking <= 50250 + ) + OR ( + r.rarity_ranking >= 49750 + AND r.rarity_ranking <= 50250 + ) ) - ) - AND last_updated_date < NOW() - INTERVAL 1 DAY - AND `status` = 0 - UNION ALL - SELECT - 4 AS tier, - online_id, - last_updated_date, - account_id - FROM - player - WHERE - ( - `rank` <= 10000 - OR rarity_rank <= 10000 - ) - AND last_updated_date < NOW() - INTERVAL 1 WEEK - AND `status` = 0 - UNION ALL - SELECT - 5 AS tier, - online_id, - last_updated_date, - account_id - FROM - player - WHERE - ( - `rank` <= 50000 - OR rarity_rank <= 50000 - ) - AND last_updated_date < NOW() - INTERVAL 1 MONTH - AND `status` = 0 - UNION ALL - SELECT - 6 AS tier, - pq.online_id, - pq.request_time, - p.account_id - FROM - player_queue pq - LEFT JOIN player p ON p.online_id = pq.online_id - WHERE - pq.request_time >= '2030-12-25 00:00:00' - UNION ALL - SELECT - 7 AS tier, - online_id, - last_updated_date, - account_id - FROM - player - WHERE - `status` != 1 - ) a - WHERE NOT EXISTS (SELECT * FROM setting WHERE scanning = a.online_id AND id != :worker_id) - ORDER BY - tier, - request_time, - online_id - LIMIT - 1 - "); - $query->bindParam(":worker_id", $worker["id"], PDO::PARAM_INT); - $query->execute(); - $player = $query->fetch(); + AND last_updated_date < NOW() - INTERVAL 1 DAY + UNION ALL + SELECT + 4 AS tier, + online_id, + last_updated_date, + account_id + FROM + player + LEFT JOIN (SELECT account_id, RANK() OVER (ORDER BY `points` DESC, `platinum` DESC, `gold` DESC, `silver` DESC) `ranking`, RANK() OVER (ORDER BY `rarity_points` DESC) `rarity_ranking` FROM `player` WHERE `status` = 0) r USING (account_id) + WHERE + ( + r.ranking <= 10000 + OR r.rarity_ranking <= 10000 + ) + AND last_updated_date < NOW() - INTERVAL 1 WEEK + UNION ALL + SELECT + 5 AS tier, + online_id, + last_updated_date, + account_id + FROM + player + LEFT JOIN (SELECT account_id, RANK() OVER (ORDER BY `points` DESC, `platinum` DESC, `gold` DESC, `silver` DESC) `ranking`, RANK() OVER (ORDER BY `rarity_points` DESC) `rarity_ranking` FROM `player` WHERE `status` = 0) r USING (account_id) + WHERE + ( + r.ranking <= 50000 + OR r.rarity_ranking <= 50000 + ) + AND last_updated_date < NOW() - INTERVAL 1 MONTH + UNION ALL + SELECT + 6 AS tier, + pq.online_id, + pq.request_time, + p.account_id + FROM + player_queue pq + LEFT JOIN player p ON p.online_id = pq.online_id + WHERE + pq.request_time >= '2030-12-25 00:00:00' + UNION ALL + SELECT + 7 AS tier, + online_id, + last_updated_date, + account_id + FROM + player + WHERE + `status` != 1 + ) a + WHERE NOT EXISTS (SELECT * FROM setting WHERE scanning = a.online_id AND id != :worker_id) + ORDER BY + tier, + request_time, + online_id + LIMIT + 1 + "); + $query->bindParam(":worker_id", $worker["id"], PDO::PARAM_INT); + $query->execute(); + $player = $query->fetch(); - $query = $database->prepare("UPDATE setting SET scanning = :scanning WHERE id = :worker_id"); - $query->bindParam(":scanning", $player["online_id"], PDO::PARAM_STR); - $query->bindParam(":worker_id", $worker["id"], PDO::PARAM_INT); - $query->execute(); + $query = $database->prepare("UPDATE setting SET scanning = :scanning WHERE id = :worker_id"); + $query->bindParam(":scanning", $player["online_id"], PDO::PARAM_STR); + $query->bindParam(":worker_id", $worker["id"], PDO::PARAM_INT); + $query->execute(); + } catch (Exception $e) { + // Probably just an exception for "Integrity constraint violation: 1062 Duplicate entry 'online_id' for key 'setting.scanning'" because another thread was faster then this one + // Continue and try again! + continue; + } if ($recheck == $player["online_id"]) { $recheck = ""; @@ -722,6 +728,10 @@ function Psn100Log($message) { try { $level = 0; $level = $user->trophySummary()->level(); + } catch (TypeError $e) { + // Rare error, wait 1 minute to not hammer Sony and try again. + sleep(60 * 1); + break; } catch (Exception $e) { // Profile seem to be private, set status to 3 to hide all trophies. $query = $database->prepare("UPDATE @@ -1269,71 +1279,6 @@ function Psn100Log($message) { $playerStatus = $query->fetchColumn(); if ($playerStatus == 0) { - // Update ranks - $query = $database->prepare("WITH - ranking AS( - SELECT - p.account_id, - RANK() OVER( - ORDER BY - p.points - DESC - , - p.platinum - DESC - , - p.gold - DESC - , - p.silver - DESC - ) ranking - FROM - player p - WHERE - p.status = 0) - UPDATE - player p, - ranking r - SET - p.rank = r.ranking - WHERE - p.account_id = r.account_id"); - $query->execute(); - - // Update country ranks - $query = $database->prepare("WITH - ranking AS( - SELECT - p.account_id, - RANK() OVER( - ORDER BY - p.points - DESC - , - p.platinum - DESC - , - p.gold - DESC - , - p.silver - DESC - ) ranking - FROM - player p - WHERE - p.status = 0 AND p.country = :country) - UPDATE - player p, - ranking r - SET - p.rank_country = r.ranking - WHERE - p.account_id = r.account_id"); - $query->bindParam(":country", strtolower($country), PDO::PARAM_STR); - $query->execute(); - // Update user rarity points for each game $query = $database->prepare("WITH rarity AS( @@ -1402,53 +1347,6 @@ function Psn100Log($message) { p.account_id = :account_id AND p.status = 0"); $query->bindParam(":account_id", $user->accountId(), PDO::PARAM_INT); $query->execute(); - - // Update rarity ranks - $query = $database->prepare("WITH - ranking AS( - SELECT - p.account_id, - RANK() OVER( - ORDER BY - p.rarity_points - DESC - ) ranking - FROM - player p - WHERE - p.status = 0) - UPDATE - player p, - ranking r - SET - p.rarity_rank = r.ranking - WHERE - p.account_id = r.account_id"); - $query->execute(); - - // Update country rarity ranks - $query = $database->prepare("WITH - ranking AS( - SELECT - p.account_id, - RANK() OVER( - ORDER BY - p.rarity_points - DESC - ) ranking - FROM - player p - WHERE - p.status = 0 AND p.country = :country) - UPDATE - player p, - ranking r - SET - p.rarity_rank_country = r.ranking - WHERE - p.account_id = r.account_id"); - $query->bindParam(":country", strtolower($country), PDO::PARAM_STR); - $query->execute(); } // Done with the user, update the date diff --git a/wwwroot/cron/daily.php b/wwwroot/cron/daily.php index edff60f..c03683e 100644 --- a/wwwroot/cron/daily.php +++ b/wwwroot/cron/daily.php @@ -4,96 +4,6 @@ set_time_limit(0); require_once("/home/psn100/public_html/init.php"); -// Update ranks -do { - try { - $query = $database->prepare("WITH - ranking AS( - SELECT - p.account_id, - RANK() OVER( - ORDER BY - p.points - DESC - , - p.platinum - DESC - , - p.gold - DESC - , - p.silver - DESC - ) ranking - FROM - player p - WHERE - p.status = 0) - UPDATE - player p, - ranking r - SET - p.rank = r.ranking - WHERE - p.account_id = r.account_id"); - $query->execute(); - - $deadlock = false; - } catch (Exception $e) { - sleep(3); - $deadlock = true; - } -} while ($deadlock); - -$countryQuery = $database->prepare("SELECT DISTINCT - (country) - FROM - player - ORDER BY NULL"); -$countryQuery->execute(); -while ($country = $countryQuery->fetch()) { - do { - try { - $query = $database->prepare("WITH - ranking AS( - SELECT - p.account_id, - RANK() OVER( - ORDER BY - p.points - DESC - , - p.platinum - DESC - , - p.gold - DESC - , - p.silver - DESC - ) ranking - FROM - player p - WHERE - p.status = 0 AND p.country = :country) - UPDATE - player p, - ranking r - SET - p.rank_country = r.ranking - WHERE - p.account_id = r.account_id"); - $query->bindParam(":country", $country["country"], PDO::PARAM_STR); - $query->execute(); - - $deadlock = false; - } catch (Exception $e) { - sleep(3); - $deadlock = true; - } - } while ($deadlock); -} - // Recalculate trophy rarity percent and rarity name. $gameQuery = $database->prepare("SELECT np_communication_id FROM trophy_title"); $gameQuery->execute(); @@ -114,7 +24,7 @@ order_id FROM trophy_earned te - LEFT JOIN player p ON p.account_id = te.account_id AND p.status = 0 AND p.rank <= 50000 + LEFT JOIN player_extra p ON p.account_id = te.account_id AND p.rank <= 50000 JOIN trophy t USING(np_communication_id, order_id) WHERE te.np_communication_id = :np_communication_id AND te.earned = 1 diff --git a/wwwroot/cron/hourly.php b/wwwroot/cron/hourly.php index 439b791..0c74698 100644 --- a/wwwroot/cron/hourly.php +++ b/wwwroot/cron/hourly.php @@ -4,6 +4,23 @@ set_time_limit(0); require_once("/home/psn100/public_html/init.php"); +// Store temp ranking +do { + try { + $query = $database->prepare("TRUNCATE TABLE `player_extra`"); + $query->execute(); + + $query = $database->prepare("INSERT INTO player_extra(`account_id`, `rank`) + SELECT `account_id`, RANK() OVER (ORDER BY `points` DESC, `platinum` DESC, `gold` DESC, `silver` DESC) `ranking` FROM player WHERE `status` = 0"); + $query->execute(); + + $deadlock = false; + } catch (Exception $e) { + sleep(3); + $deadlock = true; + } +} while ($deadlock); + // Recalculate recent players do { try { @@ -14,9 +31,9 @@ COUNT(*) AS recent_players FROM trophy_title_player ttp - JOIN player p USING(account_id) + JOIN (SELECT `account_id`, `rank` FROM player_extra) p USING (account_id) WHERE - p.status = 0 AND p.rank <= 50000 AND ttp.last_updated_date >= DATE(NOW()) - INTERVAL 7 DAY + p.rank <= 50000 AND ttp.last_updated_date >= DATE(NOW()) - INTERVAL 7 DAY GROUP BY np_communication_id) UPDATE @@ -34,3 +51,81 @@ $deadlock = true; } } while ($deadlock); + +// Recalculate game owners +do { + try { + $query = $database->prepare("WITH + game AS( + SELECT + np_communication_id, + COUNT(*) AS count + FROM + trophy_title_player ttp + JOIN (SELECT `account_id`, `rank` FROM player_extra) p USING (account_id) + WHERE + p.rank <= 50000 + GROUP BY + np_communication_id) + UPDATE + trophy_title tt, + game g + SET + tt.owners = g.count + WHERE + tt.np_communication_id = g.np_communication_id"); + $query->execute(); + + $deadlock = false; + } catch (Exception $e) { + sleep(3); + $deadlock = true; + } +} while ($deadlock); + +// Recalculate game owners completed +do { + try { + $query = $database->prepare("WITH + game AS( + SELECT + np_communication_id, + COUNT(*) AS count + FROM + trophy_title_player ttp + JOIN (SELECT `account_id`, `rank` FROM player_extra) p USING (account_id) + WHERE + ttp.progress = 100 AND p.rank <= 50000 + GROUP BY + np_communication_id) + UPDATE + trophy_title tt, + game g + SET + tt.owners_completed = g.count + WHERE + tt.np_communication_id = g.np_communication_id"); + $query->execute(); + + $deadlock = false; + } catch (Exception $e) { + sleep(3); + $deadlock = true; + } +} while ($deadlock); + +// Recalculate game difficulty +do { + try { + $query = $database->prepare("UPDATE + trophy_title + SET + difficulty = IF(owners = 0, 0, (owners_completed / owners) * 100)"); + $query->execute(); + + $deadlock = false; + } catch (Exception $e) { + sleep(3); + $deadlock = true; + } +} while ($deadlock); diff --git a/wwwroot/cron/weekly.php b/wwwroot/cron/weekly.php index 95c2035..73041b3 100644 --- a/wwwroot/cron/weekly.php +++ b/wwwroot/cron/weekly.php @@ -4,18 +4,70 @@ set_time_limit(0); require_once("/home/psn100/public_html/init.php"); +// Set ranks last week do { try { - $query = $database->prepare("UPDATE player - SET rank_last_week = `rank`, - rarity_rank_last_week = rarity_rank, - rank_country_last_week = rank_country, - rarity_rank_country_last_week = rarity_rank_country "); + $query = $database->prepare("WITH + ranking AS( + SELECT + p.account_id, + RANK() OVER(ORDER BY p.points DESC, p.platinum DESC, p.gold DESC, p.silver DESC) ranking, + RANK() OVER(ORDER BY p.rarity_points DESC) rarity_ranking + FROM + player p + WHERE + p.status = 0) + UPDATE + player p, + ranking r + SET + p.rank_last_week = r.ranking, + p.rarity_rank_last_week = r.rarity_ranking + WHERE + p.account_id = r.account_id"); $query->execute(); - + $deadlock = false; } catch (Exception $e) { sleep(3); $deadlock = true; } } while ($deadlock); + +$countryQuery = $database->prepare("SELECT DISTINCT + (country) + FROM + player + ORDER BY NULL"); +$countryQuery->execute(); +while ($country = $countryQuery->fetch()) { + do { + try { + $query = $database->prepare("WITH + ranking AS( + SELECT + p.account_id, + RANK() OVER(ORDER BY p.points DESC, p.platinum DESC, p.gold DESC, p.silver DESC) ranking, + RANK() OVER(ORDER BY p.rarity_points DESC) rarity_ranking + FROM + player p + WHERE + p.status = 0 AND p.country = :country) + UPDATE + player p, + ranking r + SET + p.rank_country_last_week = r.ranking, + p.rarity_rank_country_last_week = r.rarity_ranking + WHERE + p.account_id = r.account_id"); + $query->bindParam(":country", $country["country"], PDO::PARAM_STR); + $query->execute(); + + $deadlock = false; + } catch (Exception $e) { + sleep(3); + $deadlock = true; + } + } while ($deadlock); +} diff --git a/wwwroot/game_leaderboard.php b/wwwroot/game_leaderboard.php index d25ad34..d1589ac 100644 --- a/wwwroot/game_leaderboard.php +++ b/wwwroot/game_leaderboard.php @@ -46,11 +46,12 @@ } $sql = "SELECT COUNT(*) FROM trophy_title_player ttp - JOIN player p USING (account_id) - WHERE ttp.np_communication_id = :np_communication_id AND p.status = 0 AND p.rank <= 50000"; + JOIN (SELECT account_id, avatar_url, RANK() OVER (ORDER BY `points` DESC, `platinum` DESC, `gold` DESC, `silver` DESC) `ranking` FROM player WHERE `status` = 0"; if (isset($_GET["country"])) { - $sql .= " AND p.country = :country"; + $sql .= " AND `country` = :country"; } +$sql .= ") p USING (account_id) + WHERE ttp.np_communication_id = :np_communication_id AND p.ranking <= 50000"; if (isset($_GET["avatar"])) { $sql .= " AND p.avatar_url = :avatar"; } @@ -127,18 +128,17 @@ ttp.last_updated_date AS last_known_date FROM trophy_title_player ttp - JOIN player p ON p.account_id = ttp.account_id - AND p.status = 0 - AND p.rank <= 50000"; + JOIN (SELECT account_id, avatar_url, country, online_id, RANK() OVER (ORDER BY `points` DESC, `platinum` DESC, `gold` DESC, `silver` DESC) `ranking` FROM player WHERE `status` = 0"; if (isset($_GET["country"])) { - $sql .= " AND p.country = :country"; + $sql .= " AND `country` = :country"; } + $sql .= ") p USING (account_id)"; + $sql .= " WHERE + ttp.np_communication_id = :np_communication_id AND p.ranking <= 50000"; if (isset($_GET["avatar"])) { $sql .= " AND p.avatar_url = :avatar"; } - $sql .= " WHERE - ttp.np_communication_id = :np_communication_id - ORDER BY + $sql .= " ORDER BY progress DESC, platinum DESC, gold DESC, diff --git a/wwwroot/game_recent_players.php b/wwwroot/game_recent_players.php index e3d3901..37974a3 100644 --- a/wwwroot/game_recent_players.php +++ b/wwwroot/game_recent_players.php @@ -98,18 +98,17 @@ ttp.last_updated_date AS last_known_date FROM trophy_title_player ttp - JOIN player p ON p.account_id = ttp.account_id - AND p.status = 0 - AND p.rank <= 50000"; + JOIN (SELECT account_id, avatar_url, country, online_id, RANK() OVER (ORDER BY `points` DESC, `platinum` DESC, `gold` DESC, `silver` DESC) `ranking` FROM player WHERE `status` = 0"; if (isset($_GET["country"])) { - $sql .= " AND p.country = :country"; + $sql .= " AND `country` = :country"; } + $sql .= ") p USING (account_id)"; + $sql .= " WHERE + ttp.np_communication_id = :np_communication_id AND p.ranking <= 50000"; if (isset($_GET["avatar"])) { $sql .= " AND p.avatar_url = :avatar"; } - $sql .= " WHERE - ttp.np_communication_id = :np_communication_id - ORDER BY + $sql .= " ORDER BY last_known_date DESC LIMIT 10"; diff --git a/wwwroot/index.php b/wwwroot/index.php index b9c561b..dacb436 100644 --- a/wwwroot/index.php +++ b/wwwroot/index.php @@ -133,6 +133,22 @@ die(); } + $query = $database->prepare("SELECT country FROM player WHERE account_id = :account_id"); + $query->bindParam(":account_id", $accountId, PDO::PARAM_INT); + $query->execute(); + $playerCountry = $query->fetchColumn(); + + $query = $database->prepare("SELECT + p.*, r1.ranking, r1.rarity_ranking, r2.ranking_country, r2.rarity_ranking_country + FROM player p + LEFT JOIN (SELECT account_id, RANK() OVER (ORDER BY `points` DESC, `platinum` DESC, `gold` DESC, `silver` DESC) `ranking`, RANK() OVER (ORDER BY `rarity_points` DESC) `rarity_ranking` FROM `player` WHERE `status` = 0) r1 ON p.account_id = r1.account_id + LEFT JOIN (SELECT account_id, RANK() OVER (ORDER BY `points` DESC, `platinum` DESC, `gold` DESC, `silver` DESC) `ranking_country`, RANK() OVER (ORDER BY `rarity_points` DESC) `rarity_ranking_country` FROM `player` WHERE `status` = 0 AND `country` = :country) r2 ON p.account_id = r2.account_id + WHERE p.account_id = :account_id"); + $query->bindParam(":country", $playerCountry, PDO::PARAM_STR); + $query->bindParam(":account_id", $accountId, PDO::PARAM_INT); + $query->execute(); + $player = $query->fetch(); + switch (array_shift($elements)) { case "": require_once("player.php"); diff --git a/wwwroot/leaderboard_main.php b/wwwroot/leaderboard_main.php index c5ea416..3201259 100644 --- a/wwwroot/leaderboard_main.php +++ b/wwwroot/leaderboard_main.php @@ -85,27 +85,24 @@ prepare($sql); - if (!empty($_GET["country"])) { - $country = $_GET["country"]; - $query->bindParam(":country", $country, PDO::PARAM_STR); - } - if (!empty($_GET["avatar"])) { - $avatar = $_GET["avatar"]; - $query->bindParam(":avatar", $avatar, PDO::PARAM_STR); - } - } else { - $query = $database->prepare("SELECT * FROM player WHERE `status` = 0 ORDER BY `rank` LIMIT :offset, :limit"); + $query = $database->prepare($sql); + if (!empty($_GET["country"])) { + $country = $_GET["country"]; + $query->bindParam(":country", $country, PDO::PARAM_STR); + } + if (!empty($_GET["avatar"])) { + $avatar = $_GET["avatar"]; + $query->bindParam(":avatar", $avatar, PDO::PARAM_STR); } $query->bindParam(":offset", $offset, PDO::PARAM_INT); $query->bindParam(":limit", $limit, PDO::PARAM_INT); @@ -132,14 +129,14 @@ if ($player["rank_country_last_week"] == 0 || $player["rank_country_last_week"] == 16777215) { echo "New!"; } else { - $delta = $player["rank_country_last_week"] - $player["rank_country"]; + $delta = $player["rank_country_last_week"] - $player["ranking"]; echo "
"; if ($delta > 0) { echo ""; } - echo $player["rank_country"]; + echo $player["ranking"]; if ($delta < 0) { echo ""; @@ -150,14 +147,14 @@ if ($player["rank_last_week"] == 0 || $player["rank_last_week"] == 16777215) { echo "New!"; } else { - $delta = $player["rank_last_week"] - $player["rank"]; + $delta = $player["rank_last_week"] - $player["ranking"]; echo "
"; if ($delta > 0) { echo ""; } - echo $player["rank"]; + echo $player["ranking"]; if ($delta < 0) { echo ""; diff --git a/wwwroot/leaderboard_rarity.php b/wwwroot/leaderboard_rarity.php index 5720bdd..9d166b8 100644 --- a/wwwroot/leaderboard_rarity.php +++ b/wwwroot/leaderboard_rarity.php @@ -85,27 +85,24 @@ prepare($sql); - if (!empty($_GET["country"])) { - $country = $_GET["country"]; - $query->bindParam(":country", $country, PDO::PARAM_STR); - } - if (!empty($_GET["avatar"])) { - $avatar = $_GET["avatar"]; - $query->bindParam(":avatar", $avatar, PDO::PARAM_STR); - } - } else { - $query = $database->prepare("SELECT * FROM player WHERE `status` = 0 ORDER BY rarity_rank LIMIT :offset, :limit"); + $query = $database->prepare($sql); + if (!empty($_GET["country"])) { + $country = $_GET["country"]; + $query->bindParam(":country", $country, PDO::PARAM_STR); + } + if (!empty($_GET["avatar"])) { + $avatar = $_GET["avatar"]; + $query->bindParam(":avatar", $avatar, PDO::PARAM_STR); } $query->bindParam(":offset", $offset, PDO::PARAM_INT); $query->bindParam(":limit", $limit, PDO::PARAM_INT); @@ -131,14 +128,14 @@ if ($player["rarity_rank_country_last_week"] == 0 || $player["rarity_rank_country_last_week"] == 16777215) { echo "New!"; } else { - $delta = $player["rarity_rank_country_last_week"] - $player["rarity_rank_country"]; + $delta = $player["rarity_rank_country_last_week"] - $player["ranking"]; echo "
"; if ($delta > 0) { echo ""; } - echo $player["rarity_rank_country"]; + echo $player["ranking"]; if ($delta < 0) { echo ""; @@ -149,14 +146,14 @@ if ($player["rarity_rank_last_week"] == 0 || $player["rarity_rank_last_week"] == 16777215) { echo "New!"; } else { - $delta = $player["rarity_rank_last_week"] - $player["rarity_rank"]; + $delta = $player["rarity_rank_last_week"] - $player["ranking"]; echo "
"; if ($delta > 0) { echo ""; } - echo $player["rarity_rank"]; + echo $player["ranking"]; if ($delta < 0) { echo ""; diff --git a/wwwroot/player.php b/wwwroot/player.php index dd457f2..7de1529 100644 --- a/wwwroot/player.php +++ b/wwwroot/player.php @@ -4,11 +4,6 @@ die(); } -$query = $database->prepare("SELECT * FROM player WHERE account_id = :account_id"); -$query->bindParam(":account_id", $accountId, PDO::PARAM_INT); -$query->execute(); -$player = $query->fetch(); - $query = $database->prepare("SELECT COUNT(*) FROM trophy_title_player ttp JOIN trophy_title tt USING (np_communication_id) WHERE tt.status = 0 AND ttp.account_id = :account_id"); $query->bindParam(":account_id", $accountId, PDO::PARAM_INT); $query->execute(); diff --git a/wwwroot/player_advisor.php b/wwwroot/player_advisor.php index 4bd0352..fc74ba9 100644 --- a/wwwroot/player_advisor.php +++ b/wwwroot/player_advisor.php @@ -4,11 +4,6 @@ die(); } -$query = $database->prepare("SELECT * FROM player WHERE account_id = :account_id"); -$query->bindParam(":account_id", $accountId, PDO::PARAM_INT); -$query->execute(); -$player = $query->fetch(); - $url = $_SERVER["REQUEST_URI"]; $url_parts = parse_url($url); // If URL doesn't have a query string. diff --git a/wwwroot/player_header.php b/wwwroot/player_header.php index 6ec3fc4..13e09bb 100644 --- a/wwwroot/player_header.php +++ b/wwwroot/player_header.php @@ -38,7 +38,7 @@
50000) { + } elseif ($player["ranking"] > 50000) { ?>