diff --git a/lib/Database.php b/lib/Database.php index b7b4488..0df46df 100644 --- a/lib/Database.php +++ b/lib/Database.php @@ -731,30 +731,32 @@ class Database { // create a complex query $q = new Query( "SELECT - arsse_subscriptions.id as id, - arsse_subscriptions.feed as feed, - url,favicon,source,folder,pinned,err_count,err_msg,order_type,added, - arsse_feeds.updated as updated, - arsse_feeds.modified as edited, - arsse_subscriptions.modified as modified, - topmost.top as top_folder, - coalesce(arsse_subscriptions.title, arsse_feeds.title) as title, + s.id as id, + s.feed as feed, + f.url,source,folder,pinned,err_count,err_msg,order_type,added, + f.updated as updated, + f.modified as edited, + s.modified as modified, + i.url as favicon, + t.top as top_folder, + coalesce(s.title, f.title) as title, (articles - marked) as unread - FROM arsse_subscriptions - left join topmost on topmost.f_id = arsse_subscriptions.folder - join arsse_feeds on arsse_feeds.id = arsse_subscriptions.feed - left join (select feed, count(*) as articles from arsse_articles group by feed) as article_stats on article_stats.feed = arsse_subscriptions.feed - left join (select subscription, sum(\"read\") as marked from arsse_marks group by subscription) as mark_stats on mark_stats.subscription = arsse_subscriptions.id" + FROM arsse_subscriptions as s + left join topmost as t on t.f_id = s.folder + join arsse_feeds as f on f.id = s.feed + left join arsse_icons as i on i.id = f.icon + left join (select feed, count(*) as articles from arsse_articles group by feed) as article_stats on article_stats.feed = s.feed + left join (select subscription, sum(\"read\") as marked from arsse_marks group by subscription) as mark_stats on mark_stats.subscription = s.id" ); - $q->setWhere("arsse_subscriptions.owner = ?", ["str"], [$user]); + $q->setWhere("s.owner = ?", ["str"], [$user]); $nocase = $this->db->sqlToken("nocase"); - $q->setOrder("pinned desc, coalesce(arsse_subscriptions.title, arsse_feeds.title) collate $nocase"); + $q->setOrder("pinned desc, coalesce(s.title, f.title) collate $nocase"); // topmost folders belonging to the user $q->setCTE("topmost(f_id,top)", "SELECT id,id from arsse_folders where owner = ? and parent is null union all select id,top from arsse_folders join topmost on parent=f_id", ["str"], [$user]); if ($id) { // this condition facilitates the implementation of subscriptionPropertiesGet, which would otherwise have to duplicate the complex query; it takes precedence over a specified folder // if an ID is specified, add a suitable WHERE condition and bindings - $q->setWhere("arsse_subscriptions.id = ?", "int", $id); + $q->setWhere("s.id = ?", "int", $id); } elseif ($folder && $recursive) { // if a folder is specified and we're listing recursively, add a common table expression to list it and its children so that we select from the entire subtree $q->setCTE("folders(folder)", "SELECT ? union all select id from arsse_folders join folders on parent = folder", "int", $folder); @@ -921,13 +923,13 @@ class Database { * @param string|null $user The user who owns the subscription being queried */ public function subscriptionFavicon(int $id, string $user = null): string { - $q = new Query("SELECT favicon from arsse_feeds join arsse_subscriptions on feed = arsse_feeds.id"); - $q->setWhere("arsse_subscriptions.id = ?", "int", $id); + $q = new Query("SELECT i.url as favicon from arsse_feeds as f left join arsse_icons as i on i.id = f.icon join arsse_subscriptions as s on s.feed = f.id"); + $q->setWhere("s.id = ?", "int", $id); if (isset($user)) { if (!Arsse::$user->authorize($user, __FUNCTION__)) { throw new User\ExceptionAuthz("notAuthorized", ["action" => __FUNCTION__, "user" => $user]); } - $q->setWhere("arsse_subscriptions.owner = ?", "str", $user); + $q->setWhere("s.owner = ?", "str", $user); } return (string) $this->db->prepare($q->getQuery(), $q->getTypes())->run($q->getValues())->getValue(); } @@ -1140,8 +1142,7 @@ class Database { } // lastly update the feed database itself with updated information. $this->db->prepare( - "UPDATE arsse_feeds SET title = ?, favicon = ?, source = ?, updated = CURRENT_TIMESTAMP, modified = ?, etag = ?, err_count = 0, err_msg = '', next_fetch = ?, size = ? WHERE id = ?", - 'str', + "UPDATE arsse_feeds SET title = ?, source = ?, updated = CURRENT_TIMESTAMP, modified = ?, etag = ?, err_count = 0, err_msg = '', next_fetch = ?, size = ? WHERE id = ?", 'str', 'str', 'datetime', @@ -1151,7 +1152,6 @@ class Database { 'int' )->run( $feed->data->title, - $feed->favicon, $feed->data->siteUrl, $feed->lastModified, $feed->resource->getEtag(), diff --git a/sql/MySQL/6.sql b/sql/MySQL/6.sql index 248a014..281467e 100644 --- a/sql/MySQL/6.sql +++ b/sql/MySQL/6.sql @@ -2,6 +2,8 @@ -- Copyright 2017 J. King, Dustin Wilson et al. -- See LICENSE and AUTHORS files for details +-- Please consult the SQLite 3 schemata for commented version + alter table arsse_users add column num bigint unsigned unique; alter table arsse_users add column admin boolean not null default 0; alter table arsse_users add column lang longtext; @@ -18,4 +20,20 @@ where u.id = n.id; drop table arsse_users_existing; alter table arsse_users modify num bigint unsigned not null; +create table arsse_icons( + id serial primary key, + url varchar(767) unique not null, + modified datetime(0), + etag varchar(255) not null default '', + next_fetch datetime(0), + orphaned datetime(0), + type text, + data longblob +) character set utf8mb4 collate utf8mb4_unicode_ci; +insert into arsse_icons(url) select distinct favicon from arsse_feeds where favicon is not null; +alter table arsse_feeds add column icon bigint unsigned; +alter table arsse_feeds add constraint foreign key (icon) references arsse_icons(id) on delete set null; +update arsse_feeds as f, arsse_icons as i set f.icon = i.id where f.favicon = i.url; +alter table arsse_feeds drop column favicon; + update arsse_meta set value = '7' where "key" = 'schema_version'; diff --git a/sql/PostgreSQL/6.sql b/sql/PostgreSQL/6.sql index bc36570..6c128a0 100644 --- a/sql/PostgreSQL/6.sql +++ b/sql/PostgreSQL/6.sql @@ -2,6 +2,8 @@ -- Copyright 2017 J. King, Dustin Wilson et al. -- See LICENSE and AUTHORS files for details +-- Please consult the SQLite 3 schemata for commented version + alter table arsse_users add column num bigint unique; alter table arsse_users add column admin smallint not null default 0; alter table arsse_users add column lang text; @@ -19,4 +21,19 @@ where u.id = e.id; drop table arsse_users_existing; alter table arsse_users alter column num set not null; +create table arsse_icons( + id bigserial primary key, + url text unique not null, + modified timestamp(0) without time zone, + etag text not null default '', + next_fetch timestamp(0) without time zone, + orphaned timestamp(0) without time zone, + type text, + data bytea +); +insert into arsse_icons(url) select distinct favicon from arsse_feeds where favicon is not null; +alter table arsse_feeds add column icon bigint references arsse_icons(id) on delete set null; +update arsse_feeds as f set icon = i.id from arsse_icons as i where f.favicon = i.url; +alter table arsse_feeds drop column favicon; + update arsse_meta set value = '7' where "key" = 'schema_version'; diff --git a/sql/SQLite3/6.sql b/sql/SQLite3/6.sql index 142fada..ab82afc 100644 --- a/sql/SQLite3/6.sql +++ b/sql/SQLite3/6.sql @@ -27,6 +27,64 @@ drop table arsse_users; drop table arsse_users_existing; alter table arsse_users_new rename to arsse_users; +-- Add a separate table for feed icons and replace their URLs in the feeds table with their IDs +create table arsse_icons( + -- Icons associated with feeds + -- At a minimum the URL of the icon must be known, but its content may be missing + id integer primary key, -- the identifier for the icon + url text unique not null, -- the URL of the icon + modified text, -- Last-Modified date, for caching + etag text not null default '', -- ETag, for caching + next_fetch text, -- The date at which cached data should be considered stale + orphaned text, -- time at which the icon last had no feeds associated with it + type text, -- the Content-Type of the icon, if known + data blob -- the binary data of the icon itself +); +insert into arsse_icons(url) select distinct favicon from arsse_feeds where favicon is not null; +create table arsse_feeds_new( +-- newsfeeds, deduplicated +-- users have subscriptions to these feeds in another table + id integer primary key, -- sequence number + url text not null, -- URL of feed + title text collate nocase, -- default title of feed (users can set the title of their subscription to the feed) + source text, -- URL of site to which the feed belongs + updated text, -- time at which the feed was last fetched + modified text, -- time at which the feed last actually changed + next_fetch text, -- time at which the feed should next be fetched + orphaned text, -- time at which the feed last had no subscriptions + etag text not null default '', -- HTTP ETag hash used for cache validation, changes each time the content changes + err_count integer not null default 0, -- count of successive times update resulted in error since last successful update + err_msg text, -- last error message + username text not null default '', -- HTTP authentication username + password text not null default '', -- HTTP authentication password (this is stored in plain text) + size integer not null default 0, -- number of articles in the feed at last fetch + scrape boolean not null default 0, -- whether to use picoFeed's content scraper with this feed + icon integer references arsse_icons(id) on delete set null, -- numeric identifier of any associated icon + unique(url,username,password) -- a URL with particular credentials should only appear once +); +insert into arsse_feeds_new + select f.id, f.url, title, source, updated, f.modified, f.next_fetch, f.orphaned, f.etag, err_count, err_msg, username, password, size, scrape, i.id + from arsse_feeds as f left join arsse_icons as i on f.favicon = i.url; +drop table arsse_feeds; +alter table arsse_feeds_new rename to arsse_feeds; + + + + + + + + + + + + + + + + + + -- set version marker pragma user_version = 7; update arsse_meta set value = '7' where "key" = 'schema_version'; diff --git a/tests/cases/Database/SeriesSubscription.php b/tests/cases/Database/SeriesSubscription.php index c0a88f4..427a984 100644 --- a/tests/cases/Database/SeriesSubscription.php +++ b/tests/cases/Database/SeriesSubscription.php @@ -41,6 +41,15 @@ trait SeriesSubscription { [6, "john.doe@example.com", 2, "Politics"], ], ], + 'arsse_icons' => [ + 'columns' => [ + 'id' => "int", + 'url' => "str", + ], + 'rows' => [ + [1,"http://example.com/favicon.ico"], + ], + ], 'arsse_feeds' => [ 'columns' => [ 'id' => "int", @@ -50,7 +59,7 @@ trait SeriesSubscription { 'password' => "str", 'updated' => "datetime", 'next_fetch' => "datetime", - 'favicon' => "str", + 'icon' => "int", ], 'rows' => [], // filled in the series setup ], @@ -136,9 +145,9 @@ trait SeriesSubscription { ], ]; $this->data['arsse_feeds']['rows'] = [ - [1,"http://example.com/feed1", "Ook", "", "",strtotime("now"),strtotime("now"),''], - [2,"http://example.com/feed2", "eek", "", "",strtotime("now - 1 hour"),strtotime("now - 1 hour"),'http://example.com/favicon.ico'], - [3,"http://example.com/feed3", "Ack", "", "",strtotime("now + 1 hour"),strtotime("now + 1 hour"),''], + [1,"http://example.com/feed1", "Ook", "", "",strtotime("now"),strtotime("now"),null], + [2,"http://example.com/feed2", "eek", "", "",strtotime("now - 1 hour"),strtotime("now - 1 hour"),1], + [3,"http://example.com/feed3", "Ack", "", "",strtotime("now + 1 hour"),strtotime("now + 1 hour"),null], ]; // initialize a partial mock of the Database object to later manipulate the feedUpdate method Arsse::$db = \Phake::partialMock(Database::class, static::$drv); diff --git a/tests/cases/Db/BaseUpdate.php b/tests/cases/Db/BaseUpdate.php index b25e472..ba93687 100644 --- a/tests/cases/Db/BaseUpdate.php +++ b/tests/cases/Db/BaseUpdate.php @@ -142,14 +142,34 @@ class BaseUpdate extends \JKingWeb\Arsse\Test\AbstractTest { INSERT INTO arsse_users values('b', 'abc'); INSERT INTO arsse_folders(owner,name) values('a', '1'); INSERT INTO arsse_folders(owner,name) values('b', '2'); + INSERT INTO arsse_feeds(url,favicon) values('http://example.com/', 'http://example.com/icon'); + INSERT INTO arsse_feeds(url,favicon) values('http://example.org/', 'http://example.org/icon'); + INSERT INTO arsse_feeds(url,favicon) values('https://example.com/', 'http://example.com/icon'); + INSERT INTO arsse_feeds(url,favicon) values('http://example.net/', null); QUERY_TEXT ); $this->drv->schemaUpdate(7); - $exp = [ + $users = [ ['id' => "a", 'password' => "xyz", 'num' => 1], ['id' => "b", 'password' => "abc", 'num' => 2], ]; - $this->assertEquals($exp, $this->drv->query("SELECT id, password, num from arsse_users")->getAll()); - $this->assertSame(2, (int) $this->drv->query("SELECT count(*) from arsse_folders")->getValue()); + $folders = [ + ['owner' => "a", 'name' => "1"], + ['owner' => "b", 'name' => "2"], + ]; + $icons = [ + ['id' => 1, 'url' => "http://example.com/icon"], + ['id' => 2, 'url' => "http://example.org/icon"], + ]; + $feeds = [ + ['url' => 'http://example.com/', 'icon' => 1], + ['url' => 'http://example.org/', 'icon' => 2], + ['url' => 'https://example.com/', 'icon' => 1], + ['url' => 'http://example.net/', 'icon' => null], + ]; + $this->assertEquals($users, $this->drv->query("SELECT id, password, num from arsse_users order by id")->getAll()); + $this->assertEquals($folders, $this->drv->query("SELECT owner, name from arsse_folders order by owner")->getAll()); + $this->assertEquals($icons, $this->drv->query("SELECT id, url from arsse_icons order by id")->getAll()); + $this->assertEquals($feeds, $this->drv->query("SELECT url, icon from arsse_feeds order by id")->getAll()); } }