Rework SQL field length (#5788)

* SQL auto-update field length
Follow-up of https://github.com/FreshRSS/FreshRSS/pull/5756
Only for PostgreSQL and MySQL / MariaDB. Not possible for SQLite

* Account for MySQL 65535
Partial revert of https://github.com/FreshRSS/FreshRSS/pull/5756
> The maximum row size for the used table type, not counting BLOBs, is 65535. This includes storage overhead.
This commit is contained in:
Alexandre Alapetite 2023-10-31 02:01:50 +01:00 committed by GitHub
parent 4207f2a5b2
commit ad8bae5aca
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
6 changed files with 87 additions and 61 deletions

View File

@ -214,22 +214,14 @@ SQL;
return $ok;
}
private function ensureYear2038Compatible(): bool {
if ($this->pdo->dbType() !== 'sqlite') {
include_once(APP_PATH . '/SQL/install.sql.' . $this->pdo->dbType() . '.php');
if ($this->pdo->exec($GLOBALS['SQL_UPDATE_YEAR_2038']) === false) { //FreshRSS 1.23
Minz_Log::error('SQL error ' . __METHOD__ . json_encode($this->pdo->errorInfo()));
return false;
}
}
return true;
}
public function minorDbMaintenance(): void {
$catDAO = FreshRSS_Factory::createCategoryDao();
$catDAO->resetDefaultCategoryName();
$this->ensureYear2038Compatible();
include_once(APP_PATH . '/SQL/install.sql.' . $this->pdo->dbType() . '.php');
if (!empty($GLOBALS['SQL_UPDATE_MINOR']) && $this->pdo->exec($GLOBALS['SQL_UPDATE_MINOR']) === false) {
Minz_Log::error('SQL error ' . __METHOD__ . json_encode($this->pdo->errorInfo()));
}
}
private static function stdError(string $error): bool {

View File

@ -112,15 +112,15 @@ SQL;
$valuesTmp['guid'] = substr($valuesTmp['guid'], 0, 767);
$valuesTmp['guid'] = safe_ascii($valuesTmp['guid']);
$this->addEntryPrepared->bindParam(':guid', $valuesTmp['guid']);
$valuesTmp['title'] = mb_strcut($valuesTmp['title'], 0, 65535, 'UTF-8');
$valuesTmp['title'] = mb_strcut($valuesTmp['title'], 0, 8192, 'UTF-8');
$valuesTmp['title'] = safe_utf8($valuesTmp['title']);
$this->addEntryPrepared->bindParam(':title', $valuesTmp['title']);
$valuesTmp['author'] = mb_strcut($valuesTmp['author'], 0, 65535, 'UTF-8');
$valuesTmp['author'] = mb_strcut($valuesTmp['author'], 0, 1024, 'UTF-8');
$valuesTmp['author'] = safe_utf8($valuesTmp['author']);
$this->addEntryPrepared->bindParam(':author', $valuesTmp['author']);
$valuesTmp['content'] = safe_utf8($valuesTmp['content']);
$this->addEntryPrepared->bindParam(':content', $valuesTmp['content']);
$valuesTmp['link'] = substr($valuesTmp['link'], 0, 32768);
$valuesTmp['link'] = substr($valuesTmp['link'], 0, 16383);
$valuesTmp['link'] = safe_ascii($valuesTmp['link']);
$this->addEntryPrepared->bindParam(':link', $valuesTmp['link']);
$this->addEntryPrepared->bindParam(':date', $valuesTmp['date'], PDO::PARAM_INT);
@ -133,7 +133,7 @@ SQL;
$valuesTmp['is_favorite'] = $valuesTmp['is_favorite'] ? 1 : 0;
$this->addEntryPrepared->bindParam(':is_favorite', $valuesTmp['is_favorite'], PDO::PARAM_INT);
$this->addEntryPrepared->bindParam(':id_feed', $valuesTmp['id_feed'], PDO::PARAM_INT);
$valuesTmp['tags'] = mb_strcut($valuesTmp['tags'], 0, 65535, 'UTF-8');
$valuesTmp['tags'] = mb_strcut($valuesTmp['tags'], 0, 2048, 'UTF-8');
$valuesTmp['tags'] = safe_utf8($valuesTmp['tags']);
$this->addEntryPrepared->bindParam(':tags', $valuesTmp['tags']);
if (!isset($valuesTmp['attributes'])) {
@ -217,15 +217,15 @@ SQL;
$valuesTmp['guid'] = substr($valuesTmp['guid'], 0, 767);
$valuesTmp['guid'] = safe_ascii($valuesTmp['guid']);
$this->updateEntryPrepared->bindParam(':guid', $valuesTmp['guid']);
$valuesTmp['title'] = mb_strcut($valuesTmp['title'], 0, 65535, 'UTF-8');
$valuesTmp['title'] = mb_strcut($valuesTmp['title'], 0, 8192, 'UTF-8');
$valuesTmp['title'] = safe_utf8($valuesTmp['title']);
$this->updateEntryPrepared->bindParam(':title', $valuesTmp['title']);
$valuesTmp['author'] = mb_strcut($valuesTmp['author'], 0, 65535, 'UTF-8');
$valuesTmp['author'] = mb_strcut($valuesTmp['author'], 0, 1024, 'UTF-8');
$valuesTmp['author'] = safe_utf8($valuesTmp['author']);
$this->updateEntryPrepared->bindParam(':author', $valuesTmp['author']);
$valuesTmp['content'] = safe_utf8($valuesTmp['content']);
$this->updateEntryPrepared->bindParam(':content', $valuesTmp['content']);
$valuesTmp['link'] = substr($valuesTmp['link'], 0, 32768);
$valuesTmp['link'] = substr($valuesTmp['link'], 0, 16383);
$valuesTmp['link'] = safe_ascii($valuesTmp['link']);
$this->updateEntryPrepared->bindParam(':link', $valuesTmp['link']);
$this->updateEntryPrepared->bindParam(':date', $valuesTmp['date'], PDO::PARAM_INT);
@ -241,7 +241,7 @@ SQL;
$this->updateEntryPrepared->bindValue(':is_favorite', $valuesTmp['is_favorite'] ? 1 : 0, PDO::PARAM_INT);
}
$this->updateEntryPrepared->bindParam(':id_feed', $valuesTmp['id_feed'], PDO::PARAM_INT);
$valuesTmp['tags'] = mb_strcut($valuesTmp['tags'], 0, 65535, 'UTF-8');
$valuesTmp['tags'] = mb_strcut($valuesTmp['tags'], 0, 2048, 'UTF-8');
$valuesTmp['tags'] = safe_utf8($valuesTmp['tags']);
$this->updateEntryPrepared->bindParam(':tags', $valuesTmp['tags']);
if (!isset($valuesTmp['attributes'])) {

View File

@ -61,7 +61,7 @@ class FreshRSS_FeedDAO extends Minz_ModelPdo {
sanitizeHTML($valuesTmp['description'], ''),
$valuesTmp['lastUpdate'],
isset($valuesTmp['priority']) ? (int)$valuesTmp['priority'] : FreshRSS_Feed::PRIORITY_MAIN_STREAM,
mb_strcut($valuesTmp['pathEntries'], 0, 65535, 'UTF-8'),
mb_strcut($valuesTmp['pathEntries'], 0, 4096, 'UTF-8'),
base64_encode($valuesTmp['httpAuth']),
isset($valuesTmp['error']) ? (int)$valuesTmp['error'] : 0,
isset($valuesTmp['ttl']) ? (int)$valuesTmp['ttl'] : FreshRSS_Feed::TTL_DEFAULT,

View File

@ -26,8 +26,8 @@ CREATE TABLE IF NOT EXISTS `_feed` (
`description` TEXT,
`lastUpdate` BIGINT DEFAULT 0,
`priority` TINYINT(2) NOT NULL DEFAULT 10,
`pathEntries` VARCHAR(65535) DEFAULT NULL,
`httpAuth` VARCHAR(1024) DEFAULT NULL,
`pathEntries` VARCHAR(4096) DEFAULT NULL,
`httpAuth` VARCHAR(1024) CHARACTER SET latin1 COLLATE latin1_bin DEFAULT NULL,
`error` BOOLEAN DEFAULT 0,
`ttl` INT NOT NULL DEFAULT 0, -- v0.7.3
`attributes` TEXT, -- v1.11.0
@ -43,17 +43,17 @@ ENGINE = INNODB;
CREATE TABLE IF NOT EXISTS `_entry` (
`id` BIGINT NOT NULL, -- v0.7
`guid` VARCHAR(767) CHARACTER SET latin1 COLLATE latin1_bin NOT NULL, -- Maximum for UNIQUE is 767B
`title` VARCHAR(65535) NOT NULL,
`author` VARCHAR(65535),
`title` VARCHAR(8192) NOT NULL,
`author` VARCHAR(1024),
`content_bin` MEDIUMBLOB, -- v0.7
`link` VARCHAR(32768) CHARACTER SET latin1 COLLATE latin1_bin NOT NULL,
`link` VARCHAR(16383) CHARACTER SET latin1 COLLATE latin1_bin NOT NULL,
`date` BIGINT,
`lastSeen` BIGINT DEFAULT 0,
`hash` BINARY(16), -- v1.1.1
`is_read` BOOLEAN NOT NULL DEFAULT 0,
`is_favorite` BOOLEAN NOT NULL DEFAULT 0,
`id_feed` INT, -- 1.20.0
`tags` VARCHAR(65535),
`tags` VARCHAR(2048),
`attributes` TEXT, -- v1.20.0
PRIMARY KEY (`id`),
FOREIGN KEY (`id_feed`) REFERENCES `_feed`(`id`) ON DELETE CASCADE ON UPDATE CASCADE,
@ -70,17 +70,17 @@ INSERT IGNORE INTO `_category` (id, name) VALUES(1, "Uncategorized");
CREATE TABLE IF NOT EXISTS `_entrytmp` ( -- v1.7
`id` BIGINT NOT NULL,
`guid` VARCHAR(767) CHARACTER SET latin1 COLLATE latin1_bin NOT NULL,
`title` VARCHAR(65535) NOT NULL,
`author` VARCHAR(65535),
`title` VARCHAR(8192) NOT NULL,
`author` VARCHAR(1024),
`content_bin` MEDIUMBLOB,
`link` VARCHAR(32768) CHARACTER SET latin1 COLLATE latin1_bin NOT NULL,
`link` VARCHAR(16383) CHARACTER SET latin1 COLLATE latin1_bin NOT NULL,
`date` BIGINT,
`lastSeen` BIGINT DEFAULT 0,
`hash` BINARY(16),
`is_read` BOOLEAN NOT NULL DEFAULT 0,
`is_favorite` BOOLEAN NOT NULL DEFAULT 0,
`id_feed` INT, -- 1.20.0
`tags` VARCHAR(65535),
`tags` VARCHAR(2048),
`attributes` TEXT, -- v1.20.0
PRIMARY KEY (`id`),
FOREIGN KEY (`id_feed`) REFERENCES `_feed`(`id`) ON DELETE CASCADE ON UPDATE CASCADE,
@ -113,13 +113,27 @@ $GLOBALS['SQL_DROP_TABLES'] = <<<'SQL'
DROP TABLE IF EXISTS `_entrytag`, `_tag`, `_entrytmp`, `_entry`, `_feed`, `_category`;
SQL;
$GLOBALS['SQL_UPDATE_YEAR_2038'] = <<<'SQL'
ALTER TABLE `_entry` -- v1.23
$GLOBALS['SQL_UPDATE_MINOR'] = <<<'SQL'
ALTER TABLE `_feed`
MODIFY COLUMN `lastUpdate` BIGINT DEFAULT 0,
MODIFY COLUMN `pathEntries` VARCHAR(4096),
MODIFY COLUMN `httpAuth` VARCHAR(1024) CHARACTER SET latin1 COLLATE latin1_bin DEFAULT NULL;
ALTER TABLE `_entry`
MODIFY COLUMN `date` BIGINT,
MODIFY COLUMN `lastSeen` BIGINT DEFAULT 0;
MODIFY COLUMN `lastSeen` BIGINT DEFAULT 0,
MODIFY COLUMN `guid` VARCHAR(767) CHARACTER SET latin1 COLLATE latin1_bin NOT NULL,
MODIFY COLUMN `title` VARCHAR(8192) NOT NULL,
MODIFY COLUMN `author` VARCHAR(1024),
MODIFY COLUMN `link` VARCHAR(16383) CHARACTER SET latin1 COLLATE latin1_bin NOT NULL,
MODIFY COLUMN `tags` VARCHAR(2048);
ALTER TABLE `_entrytmp`
MODIFY COLUMN `date` BIGINT,
MODIFY COLUMN `lastSeen` BIGINT DEFAULT 0;
ALTER TABLE `_feed`
MODIFY COLUMN `lastUpdate` BIGINT DEFAULT 0;
MODIFY COLUMN `lastSeen` BIGINT DEFAULT 0,
MODIFY COLUMN `guid` VARCHAR(767) CHARACTER SET latin1 COLLATE latin1_bin NOT NULL,
MODIFY COLUMN `title` VARCHAR(8192) NOT NULL,
MODIFY COLUMN `author` VARCHAR(1024),
MODIFY COLUMN `link` VARCHAR(16383) CHARACTER SET latin1 COLLATE latin1_bin NOT NULL,
MODIFY COLUMN `tags` VARCHAR(2048);
ALTER TABLE `_tag`
MODIFY COLUMN `name` VARCHAR(191) NOT NULL;
SQL;

View File

@ -23,7 +23,7 @@ CREATE TABLE IF NOT EXISTS `_feed` (
"description" TEXT,
"lastUpdate" BIGINT DEFAULT 0,
"priority" SMALLINT NOT NULL DEFAULT 10,
"pathEntries" VARCHAR(65535) DEFAULT NULL,
"pathEntries" VARCHAR(4096) DEFAULT NULL,
"httpAuth" VARCHAR(1024) DEFAULT NULL,
"error" SMALLINT DEFAULT 0,
"ttl" INT NOT NULL DEFAULT 0,
@ -38,17 +38,17 @@ CREATE INDEX IF NOT EXISTS `_priority_index` ON `_feed` ("priority");
CREATE TABLE IF NOT EXISTS `_entry` (
"id" BIGINT NOT NULL PRIMARY KEY,
"guid" VARCHAR(767) NOT NULL,
"title" VARCHAR(65535) NOT NULL,
"author" VARCHAR(65535),
"title" VARCHAR(8192) NOT NULL,
"author" VARCHAR(1024),
"content" TEXT,
"link" VARCHAR(32768) NOT NULL,
"link" VARCHAR(16383) NOT NULL,
"date" BIGINT,
"lastSeen" BIGINT DEFAULT 0,
"hash" BYTEA,
"is_read" SMALLINT NOT NULL DEFAULT 0,
"is_favorite" SMALLINT NOT NULL DEFAULT 0,
"id_feed" INT, -- 1.20.0
"tags" VARCHAR(65535),
"tags" VARCHAR(2048),
"attributes" TEXT, -- v1.20.0
FOREIGN KEY ("id_feed") REFERENCES `_feed` ("id") ON DELETE CASCADE ON UPDATE CASCADE,
UNIQUE ("id_feed","guid")
@ -66,17 +66,17 @@ INSERT INTO `_category` (id, name)
CREATE TABLE IF NOT EXISTS `_entrytmp` ( -- v1.7
"id" BIGINT NOT NULL PRIMARY KEY,
"guid" VARCHAR(767) NOT NULL,
"title" VARCHAR(65535) NOT NULL,
"author" VARCHAR(65535),
"title" VARCHAR(8192) NOT NULL,
"author" VARCHAR(1024),
"content" TEXT,
"link" VARCHAR(32768) NOT NULL,
"link" VARCHAR(16383) NOT NULL,
"date" BIGINT,
"lastSeen" BIGINT DEFAULT 0,
"hash" BYTEA,
"is_read" SMALLINT NOT NULL DEFAULT 0,
"is_favorite" SMALLINT NOT NULL DEFAULT 0,
"id_feed" INT, -- 1.20.0
"tags" VARCHAR(65535),
"tags" VARCHAR(2048),
"attributes" TEXT, -- v1.20.0
FOREIGN KEY ("id_feed") REFERENCES `_feed` ("id") ON DELETE CASCADE ON UPDATE CASCADE,
UNIQUE ("id_feed","guid")
@ -102,13 +102,30 @@ $GLOBALS['SQL_DROP_TABLES'] = <<<'SQL'
DROP TABLE IF EXISTS `_entrytag`, `_tag`, `_entrytmp`, `_entry`, `_feed`, `_category`;
SQL;
$GLOBALS['SQL_UPDATE_YEAR_2038'] = <<<'SQL'
ALTER TABLE `_entry` -- v1.23
$GLOBALS['SQL_UPDATE_MINOR'] = <<<'SQL'
ALTER TABLE `_category`
ALTER COLUMN "name" SET DATA TYPE VARCHAR(191);
ALTER TABLE `_feed`
ALTER COLUMN "name" SET DATA TYPE VARCHAR(191),
ALTER COLUMN "lastUpdate" SET DATA TYPE BIGINT,
ALTER COLUMN "pathEntries" SET DATA TYPE VARCHAR(4096),
ALTER COLUMN "httpAuth" SET DATA TYPE VARCHAR(1024);
ALTER TABLE `_entry`
ALTER COLUMN "date" SET DATA TYPE BIGINT,
ALTER COLUMN "lastSeen" SET DATA TYPE BIGINT;
ALTER COLUMN "lastSeen" SET DATA TYPE BIGINT,
ALTER COLUMN "guid" SET DATA TYPE VARCHAR(767),
ALTER COLUMN "title" SET DATA TYPE VARCHAR(8192),
ALTER COLUMN "author" SET DATA TYPE VARCHAR(1024),
ALTER COLUMN "link" SET DATA TYPE VARCHAR(16383),
ALTER COLUMN "tags" SET DATA TYPE VARCHAR(2048);
ALTER TABLE `_entrytmp`
ALTER COLUMN "date" SET DATA TYPE BIGINT,
ALTER COLUMN "lastSeen" SET DATA TYPE BIGINT;
ALTER TABLE `_feed`
ALTER COLUMN "lastUpdate" SET DATA TYPE BIGINT;
ALTER COLUMN "lastSeen" SET DATA TYPE BIGINT,
ALTER COLUMN "guid" SET DATA TYPE VARCHAR(767),
ALTER COLUMN "title" SET DATA TYPE VARCHAR(8192),
ALTER COLUMN "author" SET DATA TYPE VARCHAR(1024),
ALTER COLUMN "link" SET DATA TYPE VARCHAR(16383),
ALTER COLUMN "tags" SET DATA TYPE VARCHAR(2048);
ALTER TABLE `_tag`
ALTER COLUMN "name" SET DATA TYPE VARCHAR(191);
SQL;

View File

@ -24,7 +24,7 @@ CREATE TABLE IF NOT EXISTS `feed` (
`description` TEXT,
`lastUpdate` BIGINT DEFAULT 0,
`priority` TINYINT(2) NOT NULL DEFAULT 10,
`pathEntries` VARCHAR(65535) DEFAULT NULL,
`pathEntries` VARCHAR(4096) DEFAULT NULL,
`httpAuth` VARCHAR(1024) DEFAULT NULL,
`error` BOOLEAN DEFAULT 0,
`ttl` INT NOT NULL DEFAULT 0,
@ -39,17 +39,17 @@ CREATE INDEX IF NOT EXISTS feed_priority_index ON `feed`(`priority`);
CREATE TABLE IF NOT EXISTS `entry` (
`id` BIGINT NOT NULL,
`guid` VARCHAR(767) NOT NULL,
`title` VARCHAR(65535) NOT NULL,
`author` VARCHAR(65535),
`title` VARCHAR(8192) NOT NULL,
`author` VARCHAR(1024),
`content` TEXT,
`link` VARCHAR(32768) NOT NULL,
`link` VARCHAR(16383) NOT NULL,
`date` BIGINT,
`lastSeen` BIGINT DEFAULT 0,
`hash` BINARY(16), -- v1.1.1
`is_read` BOOLEAN NOT NULL DEFAULT 0,
`is_favorite` BOOLEAN NOT NULL DEFAULT 0,
`id_feed` INTEGER, -- 1.20.0
`tags` VARCHAR(65535),
`tags` VARCHAR(2048),
`attributes` TEXT, -- v1.20.0
PRIMARY KEY (`id`),
FOREIGN KEY (`id_feed`) REFERENCES `feed`(`id`) ON DELETE CASCADE ON UPDATE CASCADE,
@ -65,17 +65,17 @@ INSERT OR IGNORE INTO `category` (id, name) VALUES(1, "Uncategorized");
CREATE TABLE IF NOT EXISTS `entrytmp` ( -- v1.7
`id` BIGINT NOT NULL,
`guid` VARCHAR(767) NOT NULL,
`title` VARCHAR(65535) NOT NULL,
`author` VARCHAR(65535),
`title` VARCHAR(8192) NOT NULL,
`author` VARCHAR(1024),
`content` TEXT,
`link` VARCHAR(32768) NOT NULL,
`link` VARCHAR(16383) NOT NULL,
`date` BIGINT,
`lastSeen` BIGINT DEFAULT 0,
`hash` BINARY(16),
`is_read` BOOLEAN NOT NULL DEFAULT 0,
`is_favorite` BOOLEAN NOT NULL DEFAULT 0,
`id_feed` INTEGER, -- 1.20.0
`tags` VARCHAR(65535),
`tags` VARCHAR(2048),
`attributes` TEXT, -- v1.20.0
PRIMARY KEY (`id`),
FOREIGN KEY (`id_feed`) REFERENCES `feed`(`id`) ON DELETE CASCADE ON UPDATE CASCADE,
@ -107,3 +107,6 @@ DROP TABLE IF EXISTS `entry`;
DROP TABLE IF EXISTS `feed`;
DROP TABLE IF EXISTS `category`;
SQL;
$GLOBALS['SQL_UPDATE_MINOR'] = <<<'SQL'
SQL;