diff options
| author | 2025-11-17 13:48:48 +0100 | |
|---|---|---|
| committer | 2025-11-17 13:48:48 +0100 | |
| commit | deb7633c4932d1838cb0a67aebdab5e37aae7206 (patch) | |
| tree | 0759233d06580ec952d050c064f547a16958db99 | |
| parent | 419a1978b6d8052f88783a4624cd17602422030a (diff) | |
Change SQL update query (#6957)
* Change SQL update query for MariaDB / MySQL
fix https://github.com/FreshRSS/FreshRSS/issues/5707
* No change for SQLite
* Fix merge error
* Update MySQL version on the model of PostgreSQL
Performance to be tested
* Fix LEFT JOIN, also for PostgreSQL / SQLite
* Fix alias
* Reduce MySQL deadlock
* Fix compatibility with SQLite
* Back to identical SQL for all databases
| -rw-r--r-- | app/Models/EntryDAO.php | 8 | ||||
| -rw-r--r-- | app/Models/FeedDAO.php | 35 | ||||
| -rw-r--r-- | app/Models/FeedDAOPGSQL.php | 36 |
3 files changed, 35 insertions, 44 deletions
diff --git a/app/Models/EntryDAO.php b/app/Models/EntryDAO.php index 572c9054d..b4f7451c7 100644 --- a/app/Models/EntryDAO.php +++ b/app/Models/EntryDAO.php @@ -1679,7 +1679,13 @@ SQL; } return $affected; } - $sql = 'UPDATE `_entry` SET `lastSeen`=? WHERE id_feed=? AND guid IN (' . str_repeat('?,', count($guids) - 1) . '?)'; + + // Reduce MySQL deadlock probability by ensuring consistent lock ordering + $orderBy = $this->pdo->dbType() === 'mysql' ? ' ORDER BY id DESC' : ''; + + $sql = 'UPDATE `_entry` ' . + 'SET `lastSeen`=? WHERE id_feed=? AND guid IN (' . str_repeat('?,', count($guids) - 1) . '?)' . + $orderBy; $stm = $this->pdo->prepare($sql); if ($mtime <= 0) { $mtime = time(); diff --git a/app/Models/FeedDAO.php b/app/Models/FeedDAO.php index 0353f9a05..ddc2057db 100644 --- a/app/Models/FeedDAO.php +++ b/app/Models/FeedDAO.php @@ -479,17 +479,38 @@ SQL; * Update cached values for selected feeds, or all feeds if no feed ID is provided. */ public function updateCachedValues(int ...$feedIds): int|false { - //2 sub-requests with FOREIGN KEY(e.id_feed), INDEX(e.is_read) faster than 1 request with GROUP BY or CASE + if (empty($feedIds)) { + $whereFeedIds = 'true'; + $whereEntryIdFeeds = 'true'; + } else { + $whereFeedIds = 'id IN (' . str_repeat('?,', count($feedIds) - 1) . '?)'; + $whereEntryIdFeeds = 'id_feed IN (' . str_repeat('?,', count($feedIds) - 1) . '?)'; + } $sql = <<<SQL + WITH entry_counts AS ( + SELECT + id_feed, + COUNT(*) AS total_entries, + SUM(CASE WHEN is_read = 0 THEN 1 ELSE 0 END) AS unread_entries + FROM `_entry` + WHERE $whereEntryIdFeeds + GROUP BY id_feed + ) UPDATE `_feed` - SET `cache_nbEntries`=(SELECT COUNT(e1.id) FROM `_entry` e1 WHERE e1.id_feed=`_feed`.id), - `cache_nbUnreads`=(SELECT COUNT(e2.id) FROM `_entry` e2 WHERE e2.id_feed=`_feed`.id AND e2.is_read=0) + SET `cache_nbEntries` = COALESCE(( + SELECT c.total_entries + FROM entry_counts AS c + WHERE c.id_feed = `_feed`.id + ), 0), + `cache_nbUnreads` = COALESCE(( + SELECT c.unread_entries + FROM entry_counts AS c + WHERE c.id_feed = `_feed`.id + ), 0) + WHERE $whereFeedIds SQL; - if (count($feedIds) > 0) { - $sql .= ' WHERE id IN (' . str_repeat('?,', count($feedIds) - 1) . '?)'; - } $stm = $this->pdo->prepare($sql); - if ($stm !== false && $stm->execute($feedIds)) { + if ($stm !== false && $stm->execute(array_merge($feedIds, $feedIds))) { return $stm->rowCount(); } else { $info = $stm === false ? $this->pdo->errorInfo() : $stm->errorInfo(); diff --git a/app/Models/FeedDAOPGSQL.php b/app/Models/FeedDAOPGSQL.php index 954a6e0ff..f436a2ec4 100644 --- a/app/Models/FeedDAOPGSQL.php +++ b/app/Models/FeedDAOPGSQL.php @@ -10,40 +10,4 @@ SELECT setval('`_feed_id_seq`', COALESCE(MAX(id), 0) + 1, false) FROM `_feed` SQL; return $this->pdo->exec($sql) !== false; } - - #[\Override] - public function updateCachedValues(int ...$feedIds): int|false { - // Faster than the MySQL version - if (empty($feedIds)) { - $whereFeedIds = 'true'; - $whereEntryIdFeeds = 'true'; - } else { - $whereFeedIds = 'id IN (' . str_repeat('?,', count($feedIds) - 1) . '?)'; - $whereEntryIdFeeds = 'id_feed IN (' . str_repeat('?,', count($feedIds) - 1) . '?)'; - } - $sql = <<<SQL - WITH entry_counts AS ( - SELECT - id_feed, - COUNT(*) AS total_entries, - SUM(CASE WHEN is_read = 0 THEN 1 ELSE 0 END) AS unread_entries - FROM `_entry` - WHERE $whereEntryIdFeeds - GROUP BY id_feed - ) - UPDATE `_feed` - SET `cache_nbEntries` = COALESCE(c.total_entries, 0), - `cache_nbUnreads` = COALESCE(c.unread_entries, 0) - FROM entry_counts c - WHERE id = c.id_feed AND $whereFeedIds - SQL; - $stm = $this->pdo->prepare($sql); - if ($stm !== false && $stm->execute(array_merge($feedIds, $feedIds))) { - return $stm->rowCount(); - } else { - $info = $stm === false ? $this->pdo->errorInfo() : $stm->errorInfo(); - Minz_Log::error('SQL error ' . __METHOD__ . json_encode($info)); - return false; - } - } } |
