From 36c6a44802ffef11191b019cfe5c7206c94ec3a7 Mon Sep 17 00:00:00 2001 From: Jason Gessner Date: Mon, 7 Oct 2024 15:52:03 +0100 Subject: [PATCH 1/4] Add missing pagedescription for trashed and restored decklists. --- src/AppBundle/Controller/DecklistsController.php | 2 ++ 1 file changed, 2 insertions(+) diff --git a/src/AppBundle/Controller/DecklistsController.php b/src/AppBundle/Controller/DecklistsController.php index 3ed443eb..0fa8bb12 100644 --- a/src/AppBundle/Controller/DecklistsController.php +++ b/src/AppBundle/Controller/DecklistsController.php @@ -99,11 +99,13 @@ public function listAction(string $type, int $page = 1, Request $request, Entity $this->denyAccessUnlessGranted('ROLE_MODERATOR'); $result = $decklistManager->trashed($start, $limit); $pagetitle = "Trashed decklists"; + $pagedescription = ''; break; case 'restored': $this->denyAccessUnlessGranted('ROLE_MODERATOR'); $result = $decklistManager->restored($start, $limit); $pagetitle = "Restored decklists"; + $pagedescription = ''; break; case 'popular': default: From f318b72bf4e03664879e2d361a0c5a63b5c05827 Mon Sep 17 00:00:00 2001 From: Jason Gessner Date: Mon, 7 Oct 2024 15:52:36 +0100 Subject: [PATCH 2/4] Remove SQL_CALC_FOUND_ROWS usage from the SocialController. --- src/AppBundle/Controller/SocialController.php | 50 +++++++++++-------- 1 file changed, 29 insertions(+), 21 deletions(-) diff --git a/src/AppBundle/Controller/SocialController.php b/src/AppBundle/Controller/SocialController.php index 338ea838..fb36c66b 100755 --- a/src/AppBundle/Controller/SocialController.php +++ b/src/AppBundle/Controller/SocialController.php @@ -1115,6 +1115,20 @@ public function unfollowAction(User $following, Request $request, EntityManagerI ])); } + private function getLimitedQueryRowsWithCounts(EntityManagerInterface $entityManager, string $baseQuery, int $start, int $limit, array $params) { + + $dbh = $entityManager->getConnection(); + + $rows = $dbh->executeQuery("$baseQuery LIMIT $start, $limit", $params)->fetchAll(\PDO::FETCH_ASSOC); + + $count = $dbh->executeQuery("SELECT COUNT(*) FROM ($baseQuery) AS t", $params)->fetch(\PDO::FETCH_NUM)[0]; + + return [ + "rows" => $rows, + "count" => $count + ]; + } + /** * @param int $page * @param Request $request @@ -1136,10 +1150,9 @@ public function usercommentsAction(int $page, Request $request, EntityManagerInt } $start = ($page - 1) * $limit; - $dbh = $entityManager->getConnection(); - - $comments = $dbh->executeQuery( - "SELECT SQL_CALC_FOUND_ROWS + $results = $this->getLimitedQueryRowsWithCounts( + $entityManager, + "SELECT c.id, c.text, c.date_creation, @@ -1150,15 +1163,10 @@ public function usercommentsAction(int $page, Request $request, EntityManagerInt from comment c join decklist d on c.decklist_id=d.id where c.user_id=? - order by date_creation desc - limit $start, $limit", - [ - $user->getId(), - ] - ) - ->fetchAll(\PDO::FETCH_ASSOC); - - $maxcount = $dbh->executeQuery("SELECT FOUND_ROWS()")->fetch(\PDO::FETCH_NUM)[0]; + order by date_creation desc", + $start, $limit, [ $user->getId() ] ); + $comments = $results['rows']; + $maxcount = $results['count']; // pagination : calcul de nbpages // currpage // prevpage // nextpage // à partir de $start, $limit, $count, $maxcount, $page @@ -1218,8 +1226,9 @@ public function commentsAction(int $page, Request $request, EntityManagerInterfa $dbh = $entityManager->getConnection(); - $comments = $dbh->executeQuery( - "SELECT SQL_CALC_FOUND_ROWS + $results = $this->getLimitedQueryRowsWithCounts( + $entityManager, + "SELECT c.id, c.text, c.date_creation, @@ -1232,12 +1241,11 @@ public function commentsAction(int $page, Request $request, EntityManagerInterfa from comment c join decklist d on c.decklist_id=d.id join user u on c.user_id=u.id - order by date_creation desc - limit $start, $limit", - [] - )->fetchAll(\PDO::FETCH_ASSOC); - - $maxcount = $dbh->executeQuery("SELECT FOUND_ROWS()")->fetch(\PDO::FETCH_NUM)[0]; + order by date_creation desc", + $start, $limit, + []); + $comments = $results['rows']; + $maxcount = $results['count']; // pagination : calcul de nbpages // currpage // prevpage // nextpage // à partir de $start, $limit, $count, $maxcount, $page From 8a9a1eac497e8f3349d5e3a30dbae91214e1870c Mon Sep 17 00:00:00 2001 From: Jason Gessner Date: Mon, 7 Oct 2024 16:17:23 +0100 Subject: [PATCH 3/4] Remove SQL_CALC_FOUND_ROWS from DecklistManager and fix some id vs code pack issues. Technically this makes the worst decklist search worse because it is taking our slowest queries and running them twice, but i'm following up with a rewrite to this query. --- src/AppBundle/Service/DecklistManager.php | 250 +++++++++------------- 1 file changed, 96 insertions(+), 154 deletions(-) diff --git a/src/AppBundle/Service/DecklistManager.php b/src/AppBundle/Service/DecklistManager.php index c83d89f4..52a83df4 100755 --- a/src/AppBundle/Service/DecklistManager.php +++ b/src/AppBundle/Service/DecklistManager.php @@ -20,6 +20,20 @@ public function __construct(EntityManagerInterface $entityManager) $this->entityManager = $entityManager; } + private function getLimitedQueryRowsWithCounts(EntityManagerInterface $entityManager, string $baseQuery, int $start, int $limit, array $params) { + + $dbh = $entityManager->getConnection(); + + $rows = $dbh->executeQuery("$baseQuery LIMIT $start, $limit", $params)->fetchAll(\PDO::FETCH_ASSOC); + + $count = $dbh->executeQuery("SELECT COUNT(*) FROM ($baseQuery) AS t", $params)->fetch(\PDO::FETCH_NUM)[0]; + + return [ + "rows" => $rows, + "count" => $count + ]; + } + /** * returns the list of decklist favorited by user * @@ -31,10 +45,9 @@ public function __construct(EntityManagerInterface $entityManager) */ public function favorites(int $user_id, int $start = 0, int $limit = 30) { - $dbh = $this->entityManager->getConnection(); - - $rows = $dbh->executeQuery( - "SELECT SQL_CALC_FOUND_ROWS + $results = $this->getLimitedQueryRowsWithCounts( + $this->entityManager, + "SELECT d.id, d.uuid, d.name, @@ -64,19 +77,12 @@ public function favorites(int $user_id, int $start = 0, int $limit = 30) left join rotation r on d.rotation_id=r.id where f.user_id=? and d.moderation_status in (0,1) - order by date_creation desc - limit $start, $limit", - [ - $user_id, - ] - ) - ->fetchAll(\PDO::FETCH_ASSOC); - - $count = $dbh->executeQuery("SELECT FOUND_ROWS()")->fetch(\PDO::FETCH_NUM)[0]; + order by date_creation desc", + $start, $limit, [ $user_id ]); return [ - "count" => $count, - "decklists" => $rows, + "count" => $results['count'], + "decklists" => $results['rows'], ]; } @@ -91,10 +97,8 @@ public function favorites(int $user_id, int $start = 0, int $limit = 30) */ public function by_author(int $user_id, int $start = 0, int $limit = 30) { - $dbh = $this->entityManager->getConnection(); - - $rows = $dbh->executeQuery( - "SELECT SQL_CALC_FOUND_ROWS + $results = $this->getLimitedQueryRowsWithCounts($this->entityManager, + "SELECT d.id, d.uuid, d.name, @@ -123,18 +127,12 @@ public function by_author(int $user_id, int $start = 0, int $limit = 30) left join rotation r on d.rotation_id=r.id where d.user_id=? and d.moderation_status in (0,1,2) - order by date_creation desc - limit $start, $limit", - [ - $user_id, - ] - )->fetchAll(\PDO::FETCH_ASSOC); - - $count = $dbh->executeQuery("SELECT FOUND_ROWS()")->fetch(\PDO::FETCH_NUM)[0]; + order by date_creation desc", + $start, $limit, [ $user_id ]); return [ - "count" => $count, - "decklists" => $rows, + "count" => $results['count'], + "decklists" => $results['rows'], ]; } @@ -145,10 +143,8 @@ public function by_author(int $user_id, int $start = 0, int $limit = 30) */ public function popular(int $start = 0, int $limit = 30) { - $dbh = $this->entityManager->getConnection(); - - $rows = $dbh->executeQuery( - "SELECT SQL_CALC_FOUND_ROWS + $results = $this->getLimitedQueryRowsWithCounts($this->entityManager, + "SELECT d.id, d.uuid, d.name, @@ -178,15 +174,11 @@ public function popular(int $start = 0, int $limit = 30) left join rotation r on d.rotation_id=r.id where d.date_creation > DATE_SUB(CURRENT_DATE, INTERVAL 1 MONTH) and d.moderation_status in (0,1) - order by 2*nbvotes/(1+nbjours*nbjours) DESC, nbvotes desc, nbcomments desc - limit $start, $limit" - )->fetchAll(\PDO::FETCH_ASSOC); - - $count = $dbh->executeQuery("SELECT FOUND_ROWS()")->fetch(\PDO::FETCH_NUM)[0]; - + order by 2*nbvotes/(1+nbjours*nbjours) DESC, nbvotes desc, nbcomments desc", + $start, $limit, []); return [ - "count" => $count, - "decklists" => $rows, + "count" => $results['count'], + "decklists" => $results['rows'], ]; } @@ -197,10 +189,8 @@ public function popular(int $start = 0, int $limit = 30) */ public function dotw(int $start = 0, int $limit = 30) { - $dbh = $this->entityManager->getConnection(); - - $rows = $dbh->executeQuery(" - SELECT SQL_CALC_FOUND_ROWS + $results = $this->getLimitedQueryRowsWithCounts($this->entityManager, + "SELECT d.id, d.uuid, d.name, @@ -228,15 +218,12 @@ public function dotw(int $start = 0, int $limit = 30) left join tournament t on d.tournament_id=t.id left join rotation r on d.rotation_id=r.id where dotw > 0 - order by dotw desc - limit $start, $limit" - )->fetchAll(\PDO::FETCH_ASSOC); - - $count = $dbh->executeQuery("SELECT FOUND_ROWS()")->fetch(\PDO::FETCH_NUM)[0]; + order by dotw desc", + $start, $limit, []); return [ - "count" => $count, - "decklists" => $rows, + "count" => $results['count'], + "decklists" => $results['rows'], ]; } @@ -247,10 +234,8 @@ public function dotw(int $start = 0, int $limit = 30) */ public function halloffame(int $start = 0, int $limit = 30) { - $dbh = $this->entityManager->getConnection(); - - $rows = $dbh->executeQuery( - "SELECT SQL_CALC_FOUND_ROWS + $results = $this->getLimitedQueryRowsWithCounts($this->entityManager, + "SELECT d.id, d.uuid, d.name, @@ -279,15 +264,12 @@ public function halloffame(int $start = 0, int $limit = 30) left join rotation r on d.rotation_id=r.id where nbvotes > 10 and d.moderation_status in (0,1) - order by nbvotes desc, date_creation desc - limit $start, $limit" - )->fetchAll(\PDO::FETCH_ASSOC); - - $count = $dbh->executeQuery("SELECT FOUND_ROWS()")->fetch(\PDO::FETCH_NUM)[0]; + order by nbvotes desc, date_creation desc", + $start, $limit, []); return [ - "count" => $count, - "decklists" => $rows, + "count" => $results['count'], + "decklists" => $results['rows'], ]; } @@ -298,10 +280,8 @@ public function halloffame(int $start = 0, int $limit = 30) */ public function hottopics(int $start = 0, int $limit = 30) { - $dbh = $this->entityManager->getConnection(); - - $rows = $dbh->executeQuery( - "SELECT SQL_CALC_FOUND_ROWS + $results = $this->getLimitedQueryRowsWithCounts($this->entityManager, + "SELECT d.id, d.uuid, d.name, @@ -331,15 +311,12 @@ public function hottopics(int $start = 0, int $limit = 30) left join rotation r on d.rotation_id=r.id where d.nbcomments > 1 and d.moderation_status in (0,1) - order by nbrecentcomments desc, date_creation desc - limit $start, $limit" - )->fetchAll(\PDO::FETCH_ASSOC); - - $count = $dbh->executeQuery("SELECT FOUND_ROWS()")->fetch(\PDO::FETCH_NUM)[0]; + order by nbrecentcomments desc, date_creation desc", + $start, $limit, []); return [ - "count" => $count, - "decklists" => $rows, + "count" => $results['count'], + "decklists" => $results['rows'], ]; } @@ -350,10 +327,8 @@ public function hottopics(int $start = 0, int $limit = 30) */ public function tournaments(int $start = 0, int $limit = 30) { - $dbh = $this->entityManager->getConnection(); - - $rows = $dbh->executeQuery( - "SELECT SQL_CALC_FOUND_ROWS + $results = $this->getLimitedQueryRowsWithCounts($this->entityManager, + "SELECT d.id, d.uuid, d.name, @@ -382,18 +357,16 @@ public function tournaments(int $start = 0, int $limit = 30) left join rotation r on d.rotation_id=r.id where d.tournament_id is not null and d.moderation_status in (0,1) - order by date_creation desc - limit $start, $limit" - )->fetchAll(\PDO::FETCH_ASSOC); - - $count = $dbh->executeQuery("SELECT FOUND_ROWS()")->fetch(\PDO::FETCH_NUM)[0]; + order by date_creation desc", + $start, $limit, []); return [ - "count" => $count, - "decklists" => $rows, + "count" => $results['count'], + "decklists" => $results['rows'], ]; } + // TODO(plural): Remove this function if truly unused. /** * returns the list of decklists of chosen faction * @param integer $limit @@ -401,10 +374,8 @@ public function tournaments(int $start = 0, int $limit = 30) */ public function faction(string $faction_code, int $start = 0, int $limit = 30) { - $dbh = $this->entityManager->getConnection(); - - $rows = $dbh->executeQuery( - "SELECT SQL_CALC_FOUND_ROWS + $results = $this->getLimitedQueryRowsWithCounts($this->entityManager, + "SELECT d.id, d.uuid, d.name, @@ -434,21 +405,16 @@ public function faction(string $faction_code, int $start = 0, int $limit = 30) left join rotation r on d.rotation_id=r.id where f.code=? and d.moderation_status in (0,1) - order by date_creation desc - limit $start, $limit", - [ - $faction_code, - ] - )->fetchAll(\PDO::FETCH_ASSOC); - - $count = $dbh->executeQuery("SELECT FOUND_ROWS()")->fetch(\PDO::FETCH_NUM)[0]; + order by date_creation desc", + $start, $limit, []); return [ - "count" => $count, - "decklists" => $rows, + "count" => $results['count'], + "decklists" => $results['rows'], ]; } + // TODO(plural): Remove this function if truly unused. /** * returns the list of decklists of chosen datapack * @param integer $limit @@ -456,10 +422,8 @@ public function faction(string $faction_code, int $start = 0, int $limit = 30) */ public function lastpack(string $pack_code, int $start = 0, int $limit = 30) { - $dbh = $this->entityManager->getConnection(); - - $rows = $dbh->executeQuery( - "SELECT SQL_CALC_FOUND_ROWS + $results = $this->getLimitedQueryRowsWithCounts($this->entityManager, + "SELECT d.id, d.uuid, d.name, @@ -488,18 +452,12 @@ public function lastpack(string $pack_code, int $start = 0, int $limit = 30) left join rotation r on d.rotation_id=r.id where p.code=? and d.moderation_status in (0,1) - order by date_creation desc - limit $start, $limit", - [ - $pack_code, - ] - )->fetchAll(\PDO::FETCH_ASSOC); - - $count = $dbh->executeQuery("SELECT FOUND_ROWS()")->fetch(\PDO::FETCH_NUM)[0]; + order by date_creation desc", + $start, $limit, [ $pack_code ]); return [ - "count" => $count, - "decklists" => $rows, + "count" => $results['count'], + "decklists" => $results['rows'], ]; } @@ -510,12 +468,10 @@ public function lastpack(string $pack_code, int $start = 0, int $limit = 30) */ public function recent(int $start = 0, int $limit = 30, bool $includeEmptyDesc = true) { - $dbh = $this->entityManager->getConnection(); - $additional_clause = $includeEmptyDesc ? "" : "and d.rawdescription!=''"; - $rows = $dbh->executeQuery( - "SELECT SQL_CALC_FOUND_ROWS + $results = $this->getLimitedQueryRowsWithCounts($this->entityManager, + "SELECT d.id, d.uuid, d.name, @@ -545,15 +501,12 @@ public function recent(int $start = 0, int $limit = 30, bool $includeEmptyDesc = where d.date_creation > DATE_SUB(CURRENT_DATE, INTERVAL 1 MONTH) and d.moderation_status in (0,1) $additional_clause - order by date_creation desc - limit $start, $limit" - )->fetchAll(\PDO::FETCH_ASSOC); - - $count = $dbh->executeQuery("SELECT FOUND_ROWS()")->fetch(\PDO::FETCH_NUM)[0]; + order by date_creation desc", + $start, $limit, []); return [ - "count" => $count, - "decklists" => $rows, + "count" => $results['count'], + "decklists" => $results['rows'], ]; } @@ -564,10 +517,8 @@ public function recent(int $start = 0, int $limit = 30, bool $includeEmptyDesc = */ public function trashed(int $start = 0, int $limit = 30) { - $dbh = $this->entityManager->getConnection(); - - $rows = $dbh->executeQuery( - "SELECT SQL_CALC_FOUND_ROWS + $results = $this->getLimitedQueryRowsWithCounts($this->entityManager, + "SELECT d.id, d.uuid, d.name, @@ -595,15 +546,12 @@ public function trashed(int $start = 0, int $limit = 30) left join tournament t on d.tournament_id=t.id left join rotation r on d.rotation_id=r.id where d.moderation_status=2 - order by date_creation desc - limit $start, $limit" - )->fetchAll(\PDO::FETCH_ASSOC); - - $count = $dbh->executeQuery("SELECT FOUND_ROWS()")->fetch(\PDO::FETCH_NUM)[0]; + order by date_creation desc", + $start, $limit, []); return [ - "count" => $count, - "decklists" => $rows, + "count" => $results['count'], + "decklists" => $results['rows'], ]; } @@ -614,10 +562,8 @@ public function trashed(int $start = 0, int $limit = 30) */ public function restored(int $start = 0, int $limit = 30) { - $dbh = $this->entityManager->getConnection(); - - $rows = $dbh->executeQuery( - "SELECT SQL_CALC_FOUND_ROWS + $results = $this->getLimitedQueryRowsWithCounts($this->entityManager, + "SELECT d.id, d.uuid, d.name, @@ -645,15 +591,12 @@ public function restored(int $start = 0, int $limit = 30) left join tournament t on d.tournament_id=t.id left join rotation r on d.rotation_id=r.id where d.moderation_status=1 - order by date_creation desc - limit $start, $limit" - )->fetchAll(\PDO::FETCH_ASSOC); - - $count = $dbh->executeQuery("SELECT FOUND_ROWS()")->fetch(\PDO::FETCH_NUM)[0]; + order by date_creation desc", + $start, $limit, []); return [ - "count" => $count, - "decklists" => $rows, + "count" => $results['count'], + "decklists" => $results['rows'], ]; } @@ -687,7 +630,7 @@ public function find(int $start = 0, int $limit = 30, Request $request, $cardsDa } if (!is_array($packs)) { - $packs = $dbh->executeQuery("SELECT id FROM pack")->fetchAll(\PDO::FETCH_COLUMN); + $packs = $dbh->executeQuery("SELECT code FROM pack")->fetchAll(\PDO::FETCH_COLUMN); } if ($faction_code === "corp" || $faction_code === "runner") { @@ -716,7 +659,7 @@ public function find(int $start = 0, int $limit = 30, Request $request, $cardsDa $ins[] = '?'; $params[] = $card->getId(); $types[] = \PDO::PARAM_STR; - $packs[] = $card->getPack()->getId(); + $packs[] = $card->getPack()->getCode(); } if (count($ins)) { $in = '(' . implode(',', $ins) . ')'; @@ -754,7 +697,6 @@ public function find(int $start = 0, int $limit = 30, Request $request, $cardsDa $params[] = '%' . $decklist_title . '%'; $types[] = \PDO::PARAM_STR; } - if (count($packs)) { $wheres[] = 'not exists(select * from decklistslot join card on decklistslot.card_id=card.id join pack on card.pack_id = pack.id where decklistslot.decklist_id=d.id and pack.code not in (?))'; $params[] = array_unique($packs); @@ -803,8 +745,8 @@ public function find(int $start = 0, int $limit = 30, Request $request, $cardsDa break; } - $rows = $dbh->executeQuery( - "SELECT SQL_CALC_FOUND_ROWS + $baseQuery = + "SELECT d.id, d.uuid, d.name, @@ -838,13 +780,13 @@ public function find(int $start = 0, int $limit = 30, Request $request, $cardsDa where $where and d.moderation_status in (0,1) $group_by - order by $order desc, d.name asc - limit $start, $limit", + order by $order desc, d.name asc"; + $rows = $dbh->executeQuery("$baseQuery limit $start, $limit", $params, $types )->fetchAll(\PDO::FETCH_ASSOC); - $count = $dbh->executeQuery("SELECT FOUND_ROWS()")->fetch(\PDO::FETCH_NUM)[0]; + $count = $dbh->executeQuery("SELECT COUNT(*) FROM ($baseQuery) AS t", $params, $types)->fetch(\PDO::FETCH_NUM)[0]; return [ "count" => $count, From 563fe4f00a56c19f7cd16b83aeaa5c4be36067ca Mon Sep 17 00:00:00 2001 From: Jason Gessner Date: Mon, 7 Oct 2024 12:44:25 -0500 Subject: [PATCH 4/4] Refactor main decklist search to be much more efficient. --- src/AppBundle/Service/DecklistManager.php | 157 +++++++++++++--------- 1 file changed, 92 insertions(+), 65 deletions(-) diff --git a/src/AppBundle/Service/DecklistManager.php b/src/AppBundle/Service/DecklistManager.php index 52a83df4..53b90665 100755 --- a/src/AppBundle/Service/DecklistManager.php +++ b/src/AppBundle/Service/DecklistManager.php @@ -638,6 +638,9 @@ public function find(int $start = 0, int $limit = 30, Request $request, $cardsDa unset($faction_code); } + // $ctes will hold the individual Common Table Expressions that make up the full decklist search query. + // While there will always be at least 1 CTE, there may be up to 4 depending on if packs and individual cards are specified. + $ctes = []; $joins = []; $wheres = []; $params = []; @@ -647,35 +650,61 @@ public function find(int $start = 0, int $limit = 30, Request $request, $cardsDa $group_by = ''; $group_by_count = 0; $ors = []; + + // If any cards are specified, they will be the latest printing IDs. + // We need to use those to get all of the card ids for every printing of those cards. + // Then, find all the decklist ids with all of those cards. if (count($cards_code)) { + $card_ids = []; $card_versions = $cardsData->get_versions_by_code($cards_code); - $versions = []; foreach ($card_versions as $card) { - $versions[$card->getTitle()][] = $card; - } - foreach (array_values($versions) as $cards) { - $ins = []; - foreach ($cards as $card) { - $ins[] = '?'; - $params[] = $card->getId(); - $types[] = \PDO::PARAM_STR; - $packs[] = $card->getPack()->getCode(); - } - if (count($ins)) { - $in = '(' . implode(',', $ins) . ')'; - $joins[] = 'dls.card_id IN ' . $in; - } + $card_ids[] = $card->getId(); } + $ctes[] = " + decklists_with_desired_cards AS ( + SELECT + decklist_id + FROM + decklistslot + WHERE + card_id IN (?) + GROUP BY + decklist_id + HAVING + COUNT(*) = ? + ) + "; + $params[] = array_unique($card_ids); + $types[] = Connection::PARAM_INT_ARRAY; + // Uses $cards_code because that is the number the user specified, not the number of printings. + $params[] = count($cards_code); + $types[] = \PDO::PARAM_INT; } - if (count($joins)) { - $join = ' JOIN decklistslot dls' - . ' ON dls.decklist_id=d.id' - . ' AND (' . implode(' OR ', $joins) . ')'; - $group_by_count = count($joins); - $group_by = ' GROUP BY dls.decklist_id' - . " HAVING COUNT(DISTINCT dls.card_id) = $group_by_count"; + // If packs are specified, things get complicated because we will be filtering OUT decklists that contain cards NOT IN any of the selected packs. + if (count($packs)) { + // First get the ids for all the unwanted cards. + $ctes[] = " + unwanted_cards AS ( + SELECT + card.id AS card_id + from + card + join pack on card.pack_id = pack.id + WHERE + pack.code NOT IN (?) + )"; + // Next, get the decklist_id for every deck that contains any of those unwanted cards. + $ctes[] = "unwanted_decklists AS ( + SELECT DISTINCT decklist_id + FROM decklistslot WHERE card_id IN (SELECT card_id FROM unwanted_cards) + )"; + $params[] = array_unique($packs); + $types[] = Connection::PARAM_STR_ARRAY; + $joins[] = "left join unwanted_decklists AS ud ON d.id = ud.decklist_id"; + $wheres[] = "ud.decklist_id IS NULL"; } + $join = implode("\n", $joins); if (!empty($side_code)) { $wheres[] = 's.code=?'; @@ -697,11 +726,6 @@ public function find(int $start = 0, int $limit = 30, Request $request, $cardsDa $params[] = '%' . $decklist_title . '%'; $types[] = \PDO::PARAM_STR; } - if (count($packs)) { - $wheres[] = 'not exists(select * from decklistslot join card on decklistslot.card_id=card.id join pack on card.pack_id = pack.id where decklistslot.decklist_id=d.id and pack.code not in (?))'; - $params[] = array_unique($packs); - $types[] = Connection::PARAM_STR_ARRAY; - } if (!empty($mwl_code)) { $wheres[] = 'exists(select * from legality join mwl on legality.mwl_id=mwl.id where legality.decklist_id=d.id and mwl.code=? and legality.is_legal=1)'; $params[] = $mwl_code; @@ -745,48 +769,51 @@ public function find(int $start = 0, int $limit = 30, Request $request, $cardsDa break; } - $baseQuery = - "SELECT - d.id, - d.uuid, - d.name, - d.prettyname, - d.date_creation, - d.user_id, - d.tournament_id, - t.description tournament, - r.name rotation, - $extra_select - u.username, - u.faction usercolor, - u.reputation, - u.donation, - c.code, - c.title identity, - c.image_url identity_url, - p.name lastpack, - d.nbvotes, - d.nbfavorites, - d.nbcomments - from decklist d - join user u on d.user_id=u.id - join side s on d.side_id=s.id - join card c on d.identity_id=c.id - join pack p on d.last_pack_id=p.id - join faction f on d.faction_id=f.id - $join - left join tournament t on d.tournament_id=t.id - left join rotation r on d.rotation_id=r.id - where $where - and d.moderation_status in (0,1) - $group_by - order by $order desc, d.name asc"; - $rows = $dbh->executeQuery("$baseQuery limit $start, $limit", + $ctes[] = + "decklist_results AS ( + SELECT + d.id, + d.uuid, + d.name, + d.prettyname, + d.date_creation, + d.user_id, + d.tournament_id, + t.description tournament, + r.name rotation, + $extra_select + u.username, + u.faction usercolor, + u.reputation, + u.donation, + c.code, + c.title identity, + c.image_url identity_url, + p.name lastpack, + d.nbvotes, + d.nbfavorites, + d.nbcomments + from decklist d + join user u on d.user_id=u.id + join side s on d.side_id=s.id + join card c on d.identity_id=c.id + join pack p on d.last_pack_id=p.id + join faction f on d.faction_id=f.id + $join + left join tournament t on d.tournament_id=t.id + left join rotation r on d.rotation_id=r.id + where $where + and d.moderation_status in (0,1) + )"; + + $baseQuery = "WITH " . implode(",\n", $ctes); + // This query isn't as simple as the ones above for the various decklist search entry points, so we can't use getLimitedQueryRowsWithCounts. + $rows = $dbh->executeQuery("$baseQuery SELECT * FROM decklist_results order by $order desc, name asc limit $start, $limit", $params, $types )->fetchAll(\PDO::FETCH_ASSOC); - $count = $dbh->executeQuery("SELECT COUNT(*) FROM ($baseQuery) AS t", $params, $types)->fetch(\PDO::FETCH_NUM)[0]; + $count = $dbh->executeQuery("$baseQuery SELECT COUNT(*) FROM decklist_results", $params, $types)->fetch(\PDO::FETCH_NUM)[0]; return [ "count" => $count,