diff --git a/CHANGELOG b/CHANGELOG index ce4bc96d..21ee2e8d 100644 --- a/CHANGELOG +++ b/CHANGELOG @@ -1,3 +1,10 @@ +Version 0.8.2 (????-??-??) +========================== + +Bug fixes: +- Enforce foreign key constraints in MySQL +- Widen most text fields for MySQL + Version 0.8.1 (2019-10-28) ========================== diff --git a/UPGRADING b/UPGRADING index c96f41c6..a78867b1 100644 --- a/UPGRADING +++ b/UPGRADING @@ -10,6 +10,14 @@ usually prudent: - If installing from source, update dependencies with: `composer install -o --no-dev` + +Upgrading from 0.8.1 to 0.8.2 +============================= + +- The database schema has changed from rev5 to rev6; if upgrading the database + manually, apply the 5.sql file + + Upgrading from 0.7.1 to 0.8.0 ============================= @@ -22,6 +30,7 @@ Upgrading from 0.7.1 to 0.8.0 - zendframework/zend-diactoros (version 2.x) - zendframework/zend-httphandlerrunner + Upgrading from 0.5.1 to 0.6.0 ============================= diff --git a/lib/Database.php b/lib/Database.php index 4036f91d..bcca3eb0 100644 --- a/lib/Database.php +++ b/lib/Database.php @@ -39,7 +39,7 @@ use JKingWeb\Arsse\Misc\URL; */ class Database { /** The version number of the latest schema the interface is aware of */ - const SCHEMA_VERSION = 5; + const SCHEMA_VERSION = 6; /** The size of a set of values beyond which the set will be embedded into the query text */ const LIMIT_SET_SIZE = 25; /** The length of a string in an embedded set beyond which a parameter placeholder will be used for the string */ @@ -50,7 +50,7 @@ class Database { const ASSOC_ADD = 1; /** Makes tag/label association change operations replace members */ const ASSOC_REPLACE = 2; - /** A map database driver short-names and their associated class names */ + /** A map of database driver short-names and their associated class names */ const DRIVER_NAMES = [ 'sqlite3' => \JKingWeb\Arsse\Db\SQLite3\Driver::class, 'postgresql' => \JKingWeb\Arsse\Db\PostgreSQL\Driver::class, @@ -520,7 +520,7 @@ class Database { if (!ValueInfo::id($id)) { throw new Db\ExceptionInput("typeViolation", ["action" => __FUNCTION__, "field" => "folder", 'type' => "int > 0"]); } - $changes = $this->db->prepare("WITH RECURSIVE folders(folder) as (SELECT ? union select id from arsse_folders join folders on parent = folder) DELETE FROM arsse_folders where owner = ? and id in (select folder from folders)", "int", "str")->run($id, $user)->changes(); + $changes = $this->db->prepare("DELETE FROM arsse_folders where owner = ? and id = ?", "str", "int")->run($user, $id)->changes(); if (!$changes) { throw new Db\ExceptionInput("subjectMissing", ["action" => __FUNCTION__, "field" => "folder", 'id' => $id]); } diff --git a/lib/Db/PostgreSQL/Driver.php b/lib/Db/PostgreSQL/Driver.php index d1ed5584..94497ddf 100644 --- a/lib/Db/PostgreSQL/Driver.php +++ b/lib/Db/PostgreSQL/Driver.php @@ -185,7 +185,7 @@ class Driver extends \JKingWeb\Arsse\Db\AbstractDriver { $dsn = $this->makeconnectionString(false, $user, $pass, $db, $host, $port, $service); set_error_handler(function(int $code, string $msg) { $msg = substr($msg, 62); - throw new Exception("connectionFailure", ["PostgreSQL", $msg]); + throw new Exception("connectionFailure", ['engine' => "PostgreSQL", 'message' => $msg]); }); try { $this->db = pg_connect($dsn, \PGSQL_CONNECT_FORCE_NEW); diff --git a/sql/MySQL/5.sql b/sql/MySQL/5.sql new file mode 100644 index 00000000..06697be4 --- /dev/null +++ b/sql/MySQL/5.sql @@ -0,0 +1,133 @@ +-- SPDX-License-Identifier: MIT +-- Copyright 2017 J. King, Dustin Wilson et al. +-- See LICENSE and AUTHORS files for details + +-- Drop unnecessary indexes +drop index id on arsse_folders; +drop index id on arsse_feeds; +drop index id on arsse_subscriptions; +drop index id on arsse_articles; +drop index id on arsse_editions; +drop index id on arsse_labels; +drop index id on arsse_tags; + +-- Ensure tables use dynamic row-format; these should be no-ops for most installations +alter table arsse_meta engine=InnoDB row_format=dynamic; +alter table arsse_users engine=InnoDB row_format=dynamic; +alter table arsse_feeds engine=InnoDB row_format=dynamic; +alter table arsse_folders engine=InnoDB row_format=dynamic; +alter table arsse_subscriptions engine=InnoDB row_format=dynamic; +alter table arsse_articles engine=InnoDB row_format=dynamic; +alter table arsse_marks engine=InnoDB row_format=dynamic; +alter table arsse_labels engine=InnoDB row_format=dynamic; +alter table arsse_label_members engine=InnoDB row_format=dynamic; +alter table arsse_tags engine=InnoDB row_format=dynamic; +alter table arsse_tag_members engine=InnoDB row_format=dynamic; +alter table arsse_editions engine=InnoDB row_format=dynamic; +alter table arsse_categories engine=InnoDB row_format=dynamic; +alter table arsse_tokens engine=InnoDB row_format=dynamic; +alter table arsse_sessions engine=InnoDB row_format=dynamic; + +-- Correct character set and collation of sessions table +alter table arsse_sessions default character set utf8mb4 collate utf8mb4_unicode_ci; +alter table arsse_sessions convert to character set utf8mb4 collate utf8mb4_unicode_ci; + +-- Ensure referential integrity +with valid as (select id from arsse_folders) + delete from arsse_folders where + owner not in (select id from arsse_users) or + (parent is not null and parent not in (select id from valid)); +delete from arsse_subscriptions where + owner not in (select id from arsse_users) or + feed not in (select id from arsse_feeds) or + (folder is not null and folder not in (select id from arsse_folders)); +delete from arsse_articles where feed not in (select id from arsse_feeds); +delete from arsse_enclosures where article not in (select id from arsse_articles); +delete from arsse_marks where + article not in (select id from arsse_articles) or + subscription not in (select id from arsse_subscriptions); +delete from arsse_editions where article not in (select id from arsse_articles); +delete from arsse_categories where article not in (select id from arsse_articles); +delete from arsse_sessions where "user" not in (select id from arsse_users); +delete from arsse_labels where owner not in (select id from arsse_users); +delete from arsse_label_members where + label not in (select id from arsse_labels) or + article not in (select id from arsse_articles) or + subscription not in (select id from arsse_subscriptions); +delete from arsse_tags where owner not in (select id from arsse_users); +delete from arsse_tag_members where + tag not in (select id from arsse_tags) or + subscription not in (select id from arsse_subscriptions); +delete from arsse_tokens where "user" not in (select id from arsse_users); + +-- Make integer foreign key referrers unsigned to match serial-type keys +alter table arsse_folders modify parent bigint unsigned; +alter table arsse_subscriptions modify feed bigint unsigned not null; +alter table arsse_subscriptions modify folder bigint unsigned; +alter table arsse_articles modify feed bigint unsigned not null; +alter table arsse_enclosures modify article bigint unsigned not null; +alter table arsse_marks modify article bigint unsigned not null; +alter table arsse_marks modify subscription bigint unsigned not null; +alter table arsse_editions modify article bigint unsigned not null; +alter table arsse_categories modify article bigint unsigned not null; +alter table arsse_label_members modify label bigint unsigned not null; +alter table arsse_label_members modify article bigint unsigned not null; +alter table arsse_label_members modify subscription bigint unsigned not null; +alter table arsse_tag_members modify tag bigint unsigned not null; +alter table arsse_tag_members modify subscription bigint unsigned not null; + +-- Use longtext columns whenever possible +alter table arsse_users modify password longtext; +alter table arsse_sessions drop primary key; +alter table arsse_sessions modify id longtext; +alter table arsse_sessions add primary key(id(768)); +alter table arsse_tokens drop primary key; +alter table arsse_tokens modify id longtext; +alter table arsse_tokens add primary key(id(512), class); +drop index url on arsse_feeds; +alter table arsse_feeds modify url longtext not null; +alter table arsse_feeds add unique index(url(255), username, password); +alter table arsse_feeds modify title longtext; +alter table arsse_feeds modify favicon longtext; +alter table arsse_feeds modify source longtext; +alter table arsse_feeds modify err_msg longtext; +alter table arsse_articles modify url longtext; +alter table arsse_articles modify title longtext; +alter table arsse_articles modify author longtext; +alter table arsse_articles modify guid longtext; +alter table arsse_enclosures modify url longtext; +alter table arsse_enclosures modify type longtext; +alter table arsse_categories modify name longtext; +drop index owner on arsse_folders; +alter table arsse_folders modify name longtext not null; +alter table arsse_folders add unique index(owner, name(255), parent); +drop index owner on arsse_tags; +alter table arsse_tags modify name longtext not null; +alter table arsse_tags add unique index(owner, name(255)); +drop index owner on arsse_labels; +alter table arsse_labels modify name longtext not null; +alter table arsse_labels add unique index(owner, name(255)); + +-- Fix foreign key constraints +alter table arsse_folders add foreign key(owner) references arsse_users(id) on delete cascade on update cascade; +alter table arsse_folders add foreign key(parent) references arsse_folders(id) on delete cascade; +alter table arsse_subscriptions add foreign key(owner) references arsse_users(id) on delete cascade on update cascade; +alter table arsse_subscriptions add foreign key(feed) references arsse_feeds(id) on delete cascade; +alter table arsse_subscriptions add foreign key(folder) references arsse_folders(id) on delete cascade; +alter table arsse_articles add foreign key(feed) references arsse_feeds(id) on delete cascade; +alter table arsse_enclosures add foreign key(article) references arsse_articles(id) on delete cascade; +alter table arsse_marks add foreign key(article) references arsse_articles(id) on delete cascade; +alter table arsse_marks add foreign key(subscription) references arsse_subscriptions(id) on delete cascade; +alter table arsse_editions add foreign key(article) references arsse_articles(id) on delete cascade; +alter table arsse_categories add foreign key(article) references arsse_articles(id) on delete cascade; +alter table arsse_sessions add foreign key("user") references arsse_users(id) on delete cascade on update cascade; +alter table arsse_labels add foreign key(owner) references arsse_users(id) on delete cascade on update cascade; +alter table arsse_label_members add foreign key(label) references arsse_labels(id) on delete cascade; +alter table arsse_label_members add foreign key(article) references arsse_articles(id) on delete cascade; +alter table arsse_label_members add foreign key(subscription) references arsse_subscriptions(id) on delete cascade; +alter table arsse_tags add foreign key(owner) references arsse_users(id) on delete cascade on update cascade; +alter table arsse_tag_members add foreign key(tag) references arsse_tags(id) on delete cascade; +alter table arsse_tag_members add foreign key(subscription) references arsse_subscriptions(id) on delete cascade; +alter table arsse_tokens add foreign key("user") references arsse_users(id) on delete cascade on update cascade; + +update arsse_meta set value = '6' where "key" = 'schema_version'; diff --git a/sql/PostgreSQL/5.sql b/sql/PostgreSQL/5.sql new file mode 100644 index 00000000..5e96fb43 --- /dev/null +++ b/sql/PostgreSQL/5.sql @@ -0,0 +1,8 @@ +-- SPDX-License-Identifier: MIT +-- Copyright 2017 J. King, Dustin Wilson et al. +-- See LICENSE and AUTHORS files for details + +-- This schema version strictly applies fixes for MySQL, +-- hence this file is functionally empty + +update arsse_meta set value = '6' where "key" = 'schema_version'; diff --git a/sql/SQLite3/5.sql b/sql/SQLite3/5.sql new file mode 100644 index 00000000..942e9a6a --- /dev/null +++ b/sql/SQLite3/5.sql @@ -0,0 +1,10 @@ +-- SPDX-License-Identifier: MIT +-- Copyright 2017 J. King, Dustin Wilson et al. +-- See LICENSE and AUTHORS files for details + +-- This schema version strictly applies fixes for MySQL, +-- hence this file is functionally empty + +-- set version marker +pragma user_version = 6; +update arsse_meta set value = '6' where "key" = 'schema_version'; diff --git a/tests/lib/DatabaseDrivers/MySQL.php b/tests/lib/DatabaseDrivers/MySQL.php index 048266d4..332f3d99 100644 --- a/tests/lib/DatabaseDrivers/MySQL.php +++ b/tests/lib/DatabaseDrivers/MySQL.php @@ -48,6 +48,7 @@ trait MySQL { $db->query("UNLOCK TABLES; ROLLBACK"); } catch (\Throwable $e) { } + $db->query("SET FOREIGN_KEY_CHECKS=0"); foreach (self::dbTableList($db) as $table) { if ($table === "arsse_meta") { $db->query("DELETE FROM $table where `key` <> 'schema_version'"); @@ -56,6 +57,7 @@ trait MySQL { } $db->query("ALTER TABLE $table auto_increment = 1"); } + $db->query("SET FOREIGN_KEY_CHECKS=1"); foreach ($afterStatements as $st) { $db->query($st); } @@ -67,9 +69,11 @@ trait MySQL { $db->query("UNLOCK TABLES; ROLLBACK"); } catch (\Throwable $e) { } + $db->query("SET FOREIGN_KEY_CHECKS=0"); foreach (self::dbTableList($db) as $table) { $db->query("DROP TABLE IF EXISTS $table"); } + $db->query("SET FOREIGN_KEY_CHECKS=1"); foreach ($afterStatements as $st) { $db->query($st); }