diff --git a/sql/PostgreSQL/0.sql b/sql/PostgreSQL/0.sql index 461b1f23..c76f6143 100644 --- a/sql/PostgreSQL/0.sql +++ b/sql/PostgreSQL/0.sql @@ -2,13 +2,25 @@ -- Copyright 2017 J. King, Dustin Wilson et al. -- See LICENSE and AUTHORS files for details --- metadata +-- Please consult the SQLite 3 schemata for commented version + +drop table if exists arsse_meta cascade; +drop table if exists arsse_users cascade; +drop table if exists arsse_users_meta cascade; +drop table if exists arsse_folders cascade; +drop table if exists arsse_feeds cascade; +drop table if exists arsse_subscriptions cascade; +drop table if exists arsse_articles cascade; +drop table if exists arsse_enclosures cascade; +drop table if exists arsse_marks cascade; +drop table if exists arsse_editions cascade; +drop table if exists arsse_categories cascade; + create table arsse_meta( key text primary key, value text ); --- users create table arsse_users( id text primary key, password text, @@ -19,7 +31,6 @@ create table arsse_users( rights bigint not null default 0 ); --- extra user metadata create table arsse_users_meta( owner text not null references arsse_users(id) on delete cascade on update cascade, key text not null, @@ -27,7 +38,6 @@ create table arsse_users_meta( primary key(owner,key) ); --- NextCloud News folders and TT-RSS categories create table arsse_folders( id bigserial primary key, owner text not null references arsse_users(id) on delete cascade on update cascade, @@ -37,7 +47,6 @@ create table arsse_folders( unique(owner,name,parent) ); --- newsfeeds, deduplicated create table arsse_feeds( id bigserial primary key, url text not null, @@ -58,7 +67,6 @@ create table arsse_feeds( unique(url,username,password) ); --- users' subscriptions to newsfeeds, with settings create table arsse_subscriptions( id bigserial primary key, owner text not null references arsse_users(id) on delete cascade on update cascade, @@ -72,7 +80,6 @@ create table arsse_subscriptions( unique(owner,feed) ); --- entries in newsfeeds create table arsse_articles( id bigserial primary key, feed bigint not null references arsse_feeds(id) on delete cascade, @@ -89,14 +96,12 @@ create table arsse_articles( title_content_hash text not null ); --- enclosures associated with articles create table arsse_enclosures( article bigint not null references arsse_articles(id) on delete cascade, url text, type text ); --- users' actions on newsfeed entries create table arsse_marks( article bigint not null references arsse_articles(id) on delete cascade, subscription bigint not null references arsse_subscriptions(id) on delete cascade on update cascade, @@ -106,18 +111,15 @@ create table arsse_marks( primary key(article,subscription) ); --- IDs for specific editions of articles (required for at least NextCloud News) create table arsse_editions( id bigserial primary key, article bigint not null references arsse_articles(id) on delete cascade, modified timestamp(0) with time zone not null default CURRENT_TIMESTAMP ); --- author categories associated with newsfeed entries create table arsse_categories( article bigint not null references arsse_articles(id) on delete cascade, name text ); --- set version marker insert into arsse_meta(key,value) values('schema_version','1'); diff --git a/sql/PostgreSQL/1.sql b/sql/PostgreSQL/1.sql index f8a950b9..5c35d6b2 100644 --- a/sql/PostgreSQL/1.sql +++ b/sql/PostgreSQL/1.sql @@ -2,7 +2,12 @@ -- Copyright 2017 J. King, Dustin Wilson et al. -- See LICENSE and AUTHORS files for details --- Sessions for Tiny Tiny RSS (and possibly others) +-- Please consult the SQLite 3 schemata for commented version + +drop table if exists arsse_sessions cascade; +drop table if exists arsse_labels cascade; +drop table if exists arsse_label_members cascade; + create table arsse_sessions ( id text primary key, created timestamp(0) with time zone not null default CURRENT_TIMESTAMP, @@ -10,7 +15,6 @@ create table arsse_sessions ( user text not null references arsse_users(id) on delete cascade on update cascade ); --- User-defined article labels for Tiny Tiny RSS create table arsse_labels ( id bigserial primary key, owner text not null references arsse_users(id) on delete cascade on update cascade, @@ -19,7 +23,6 @@ create table arsse_labels ( unique(owner,name) ); --- Labels assignments for articles create table arsse_label_members ( label bigint not null references arsse_labels(id) on delete cascade, article bigint not null references arsse_articles(id) on delete cascade, @@ -29,8 +32,6 @@ create table arsse_label_members ( primary key(label,article) ); --- alter marks table to add Tiny Tiny RSS' notes alter table arsse_marks add column note text not null default ''; --- set version marker update arsse_meta set value = '2' where key = 'schema_version'; diff --git a/sql/PostgreSQL/2.sql b/sql/PostgreSQL/2.sql index cf5cf3db..cd1fbf65 100644 --- a/sql/PostgreSQL/2.sql +++ b/sql/PostgreSQL/2.sql @@ -2,13 +2,17 @@ -- Copyright 2017 J. King, Dustin Wilson et al. -- See LICENSE and AUTHORS files for details +-- Please consult the SQLite 3 schemata for commented version + -- create a case-insensitive generic collation sequence +-- this collation is Unicode-aware, whereas SQLite's built-in nocase +-- collation is ASCII-only +drop collation if exists nocase cascade; create collation nocase( provider = icu, locale = '@kf=false' ); --- Correct collation sequences alter table arsse_users alter column id type text collate nocase; alter table arsse_folders alter column name type text collate nocase; alter table arsse_feeds alter column title type text collate nocase; @@ -18,5 +22,4 @@ alter table arsse_articles alter column author type text collate nocase; alter table arsse_categories alter column name type text collate nocase; alter table arsse_labels alter column name type text collate nocase; --- set version marker update arsse_meta set value = '3' where key = 'schema_version'; diff --git a/sql/SQLite3/0.sql b/sql/SQLite3/0.sql index add9b56b..c8ae67f9 100644 --- a/sql/SQLite3/0.sql +++ b/sql/SQLite3/0.sql @@ -5,14 +5,27 @@ -- Make the database WAL-journalled; this is persitent PRAGMA journal_mode = wal; --- metadata +-- drop any existing tables, just in case +drop table if exists arsse_meta; +drop table if exists arsse_users; +drop table if exists arsse_users_meta; +drop table if exists arsse_folders; +drop table if exists arsse_feeds; +drop table if exists arsse_subscriptions; +drop table if exists arsse_articles; +drop table if exists arsse_enclosures; +drop table if exists arsse_marks; +drop table if exists arsse_editions; +drop table if exists arsse_categories; + create table arsse_meta( +-- application metadata key text primary key not null, -- metadata key value text -- metadata value, serialized as a string ); --- users create table arsse_users( +-- users id text primary key not null, -- user id password text, -- password, salted and hashed; if using external authentication this would be blank name text, -- display name @@ -22,35 +35,38 @@ create table arsse_users( rights integer not null default 0 -- temporary admin-rights marker FIXME: remove reliance on this ); --- extra user metadata create table arsse_users_meta( +-- extra user metadata (not currently used and will be removed) owner text not null references arsse_users(id) on delete cascade on update cascade, key text not null, value text, primary key(owner,key) ); --- NextCloud News folders create table arsse_folders( +-- folders, used by NextCloud News and Tiny Tiny RSS +-- feed subscriptions may belong to at most one folder; +-- in Tiny Tiny RSS folders may nest id integer primary key, -- sequence number owner text not null references arsse_users(id) on delete cascade on update cascade, -- owner of folder parent integer references arsse_folders(id) on delete cascade, -- parent folder id name text not null, -- folder name - modified text not null default CURRENT_TIMESTAMP, -- + modified text not null default CURRENT_TIMESTAMP, -- time at which the folder itself (not its contents) was changed; not currently used unique(owner,name,parent) -- cannot have multiple folders with the same name under the same parent for the same owner ); --- newsfeeds, deduplicated create table arsse_feeds( +-- 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, -- default title of feed + title text, -- default title of feed (users can set the title of their subscription to the feed) favicon text, -- URL of favicon 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 + 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 @@ -61,13 +77,13 @@ create table arsse_feeds( unique(url,username,password) -- a URL with particular credentials should only appear once ); --- users' subscriptions to newsfeeds, with settings create table arsse_subscriptions( +-- users' subscriptions to newsfeeds, with settings id integer primary key, -- sequence number owner text not null references arsse_users(id) on delete cascade on update cascade, -- owner of subscription feed integer not null references arsse_feeds(id) on delete cascade, -- feed for the subscription added text not null default CURRENT_TIMESTAMP, -- time at which feed was added - modified text not null default CURRENT_TIMESTAMP, -- date at which subscription properties were last modified + modified text not null default CURRENT_TIMESTAMP, -- time at which subscription properties were last modified title text, -- user-supplied title order_type int not null default 0, -- NextCloud sort order pinned boolean not null default 0, -- whether feed is pinned (always sorts at top) @@ -75,16 +91,16 @@ create table arsse_subscriptions( unique(owner,feed) -- a given feed should only appear once for a given owner ); --- entries in newsfeeds create table arsse_articles( +-- entries in newsfeeds id integer primary key, -- sequence number feed integer not null references arsse_feeds(id) on delete cascade, -- feed for the subscription url text, -- URL of article title text, -- article title author text, -- author's name published text, -- time of original publication - edited text, -- time of last edit - modified text not null default CURRENT_TIMESTAMP, -- date when article properties were last modified + edited text, -- time of last edit by author + modified text not null default CURRENT_TIMESTAMP, -- time when article was last modified in database content text, -- content, as (X)HTML guid text, -- GUID url_title_hash text not null, -- hash of URL + title; used when checking for updates and for identification if there is no guid. @@ -92,34 +108,37 @@ create table arsse_articles( title_content_hash text not null -- hash of title + content, enclosure URL, & content type; used when checking for updates and for identification if there is no guid. ); --- enclosures associated with articles create table arsse_enclosures( - article integer not null references arsse_articles(id) on delete cascade, - url text, - type text +-- enclosures (attachments) associated with articles + article integer not null references arsse_articles(id) on delete cascade, -- article to which the enclosure belongs + url text, -- URL of the enclosure + type text -- content-type (MIME type) of the enclosure ); --- users' actions on newsfeed entries create table arsse_marks( - article integer not null references arsse_articles(id) on delete cascade, - subscription integer not null references arsse_subscriptions(id) on delete cascade on update cascade, - read boolean not null default 0, - starred boolean not null default 0, - modified text not null default CURRENT_TIMESTAMP, - primary key(article,subscription) + article integer not null references arsse_articles(id) on delete cascade, -- article associated with the marks + subscription integer not null references arsse_subscriptions(id) on delete cascade on update cascade, -- subscription associated with the marks; the subscription in turn belongs to a user + read boolean not null default 0, -- whether the article has been read + starred boolean not null default 0, -- whether the article is starred + modified text not null default CURRENT_TIMESTAMP, -- time at which an article was last modified by a given user + primary key(article,subscription) -- no more than one mark-set per article per user ); --- IDs for specific editions of articles (required for at least NextCloud News) create table arsse_editions( - id integer primary key, - article integer not null references arsse_articles(id) on delete cascade, - modified datetime not null default CURRENT_TIMESTAMP +-- IDs for specific editions of articles (required for at least NextCloud News) +-- every time an article is updated by its author, a new unique edition number is assigned +-- with NextCloud News this prevents users from marking as read an article which has been +-- updated since the client state was last refreshed + id integer primary key, -- sequence number + article integer not null references arsse_articles(id) on delete cascade, -- the article of which this is an edition + modified datetime not null default CURRENT_TIMESTAMP -- tiem at which the edition was modified (practically, when it was created) ); --- author categories associated with newsfeed entries create table arsse_categories( - article integer not null references arsse_articles(id) on delete cascade, - name text +-- author categories associated with newsfeed entries +-- these are not user-modifiable + article integer not null references arsse_articles(id) on delete cascade, -- article associated with the category + name text -- freeform name of the category ); -- set version marker diff --git a/sql/SQLite3/1.sql b/sql/SQLite3/1.sql index 8f273e60..1859ea89 100644 --- a/sql/SQLite3/1.sql +++ b/sql/SQLite3/1.sql @@ -2,16 +2,21 @@ -- Copyright 2017 J. King, Dustin Wilson et al. -- See LICENSE and AUTHORS files for details --- Sessions for Tiny Tiny RSS (and possibly others) +-- drop any existing tables, just in case +drop table if exists arsse_sessions; +drop table if exists arsse_labels; +drop table if exists arsse_label_members; + create table arsse_sessions ( +-- sessions for Tiny Tiny RSS (and possibly others) id text primary key, -- UUID of session created text not null default CURRENT_TIMESTAMP, -- Session start timestamp expires text not null, -- Time at which session is no longer valid user text not null references arsse_users(id) on delete cascade on update cascade -- user associated with the session ) without rowid; --- User-defined article labels for Tiny Tiny RSS create table arsse_labels ( +-- user-defined article labels for Tiny Tiny RSS id integer primary key, -- numeric ID owner text not null references arsse_users(id) on delete cascade on update cascade, -- owning user name text not null, -- label text @@ -19,30 +24,33 @@ create table arsse_labels ( unique(owner,name) ); --- Labels assignments for articles create table arsse_label_members ( - label integer not null references arsse_labels(id) on delete cascade, - article integer not null references arsse_articles(id) on delete cascade, +-- uabels assignments for articles + label integer not null references arsse_labels(id) on delete cascade, -- label ID associated to an article; label IDs belong to a user + article integer not null references arsse_articles(id) on delete cascade, -- article associated to a label subscription integer not null references arsse_subscriptions(id) on delete cascade, -- Subscription is included so that records are deleted when a subscription is removed - assigned boolean not null default 1, - modified text not null default CURRENT_TIMESTAMP, - primary key(label,article) + assigned boolean not null default 1, -- whether the association is current, to support soft deletion + modified text not null default CURRENT_TIMESTAMP, -- time at which the association was last made or unmade + primary key(label,article) -- only one association of a given label to a given article ) without rowid; -- alter marks table to add Tiny Tiny RSS' notes +-- SQLite has limited ALTER TABLE support, so the table must be re-created +-- and its data re-entered; other database systems have a much simpler prodecure alter table arsse_marks rename to arsse_marks_old; create table arsse_marks( - article integer not null references arsse_articles(id) on delete cascade, - subscription integer not null references arsse_subscriptions(id) on delete cascade on update cascade, - read boolean not null default 0, - starred boolean not null default 0, - modified text not null default CURRENT_TIMESTAMP, - note text not null default '', - primary key(article,subscription) +-- users' actions on newsfeed entries + article integer not null references arsse_articles(id) on delete cascade, -- article associated with the marks + subscription integer not null references arsse_subscriptions(id) on delete cascade on update cascade, -- subscription associated with the marks; the subscription in turn belongs to a user + read boolean not null default 0, -- whether the article has been read + starred boolean not null default 0, -- whether the article is starred + modified text not null default CURRENT_TIMESTAMP, -- time at which an article was last modified by a given user + note text not null default '', -- Tiny Tiny RSS freeform user note + primary key(article,subscription) -- no more than one mark-set per article per user ); insert into arsse_marks(article,subscription,read,starred,modified) select article,subscription,read,starred,modified from arsse_marks_old; drop table arsse_marks_old; -- set version marker pragma user_version = 2; -update arsse_meta set value = '2' where key = 'schema_version'; \ No newline at end of file +update arsse_meta set value = '2' where key = 'schema_version'; diff --git a/sql/SQLite3/2.sql b/sql/SQLite3/2.sql index 87f21efe..73402909 100644 --- a/sql/SQLite3/2.sql +++ b/sql/SQLite3/2.sql @@ -2,94 +2,106 @@ -- Copyright 2017 J. King, Dustin Wilson et al. -- See LICENSE and AUTHORS files for details --- Correct collation sequences +-- Correct collation sequences in order for various things to sort case-insensitively +-- SQLite has limited ALTER TABLE support, so the tables must be re-created +-- and their data re-entered; other database systems have a much simpler prodecure alter table arsse_users rename to arsse_users_old; create table arsse_users( - id text primary key not null collate nocase, - password text, - name text collate nocase, - avatar_type text, - avatar_data blob, - admin boolean default 0, - rights integer not null default 0 +-- users + id text primary key not null collate nocase, -- user id + password text, -- password, salted and hashed; if using external authentication this would be blank + name text collate nocase, -- display name + avatar_type text, -- internal avatar image's MIME content type + avatar_data blob, -- internal avatar image's binary data + admin boolean default 0, -- whether the user is a member of the special "admin" group + rights integer not null default 0 -- temporary admin-rights marker FIXME: remove reliance on this ); insert into arsse_users(id,password,name,avatar_type,avatar_data,admin,rights) select id,password,name,avatar_type,avatar_data,admin,rights from arsse_users_old; drop table arsse_users_old; alter table arsse_folders rename to arsse_folders_old; create table arsse_folders( - id integer primary key, - owner text not null references arsse_users(id) on delete cascade on update cascade, - parent integer references arsse_folders(id) on delete cascade, - name text not null collate nocase, - modified text not null default CURRENT_TIMESTAMP, -- - unique(owner,name,parent) +-- folders, used by NextCloud News and Tiny Tiny RSS +-- feed subscriptions may belong to at most one folder; +-- in Tiny Tiny RSS folders may nest + id integer primary key, -- sequence number + owner text not null references arsse_users(id) on delete cascade on update cascade, -- owner of folder + parent integer references arsse_folders(id) on delete cascade, -- parent folder id + name text not null collate nocase, -- folder name + modified text not null default CURRENT_TIMESTAMP, -- time at which the folder itself (not its contents) was changed; not currently used + unique(owner,name,parent) -- cannot have multiple folders with the same name under the same parent for the same owner ); insert into arsse_folders select * from arsse_folders_old; drop table arsse_folders_old; alter table arsse_feeds rename to arsse_feeds_old; create table arsse_feeds( - id integer primary key, - url text not null, - title text collate nocase, - favicon text, - source text, - updated text, - modified text, - next_fetch text, - orphaned text, - etag text not null default '', - err_count integer not null default 0, - err_msg text, - username text not null default '', - password text not null default '', - size integer not null default 0, - scrape boolean not null default 0, - unique(url,username,password) +-- 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) + favicon text, -- URL of favicon + 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 + unique(url,username,password) -- a URL with particular credentials should only appear once ); insert into arsse_feeds select * from arsse_feeds_old; drop table arsse_feeds_old; alter table arsse_subscriptions rename to arsse_subscriptions_old; create table arsse_subscriptions( - id integer primary key, - owner text not null references arsse_users(id) on delete cascade on update cascade, - feed integer not null references arsse_feeds(id) on delete cascade, - added text not null default CURRENT_TIMESTAMP, - modified text not null default CURRENT_TIMESTAMP, - title text collate nocase, - order_type int not null default 0, - pinned boolean not null default 0, - folder integer references arsse_folders(id) on delete cascade, - unique(owner,feed) +-- users' subscriptions to newsfeeds, with settings + id integer primary key, -- sequence number + owner text not null references arsse_users(id) on delete cascade on update cascade, -- owner of subscription + feed integer not null references arsse_feeds(id) on delete cascade, -- feed for the subscription + added text not null default CURRENT_TIMESTAMP, -- time at which feed was added + modified text not null default CURRENT_TIMESTAMP, -- time at which subscription properties were last modified + title text collate nocase, -- user-supplied title + order_type int not null default 0, -- NextCloud sort order + pinned boolean not null default 0, -- whether feed is pinned (always sorts at top) + folder integer references arsse_folders(id) on delete cascade, -- TT-RSS category (nestable); the first-level category (which acts as NextCloud folder) is joined in when needed + unique(owner,feed) -- a given feed should only appear once for a given owner ); insert into arsse_subscriptions select * from arsse_subscriptions_old; drop table arsse_subscriptions_old; alter table arsse_articles rename to arsse_articles_old; create table arsse_articles( - id integer primary key, - feed integer not null references arsse_feeds(id) on delete cascade, - url text, - title text collate nocase, - author text collate nocase, - published text, - edited text, - modified text not null default CURRENT_TIMESTAMP, - content text, - guid text, - url_title_hash text not null, - url_content_hash text not null, - title_content_hash text not null +-- entries in newsfeeds + id integer primary key, -- sequence number + feed integer not null references arsse_feeds(id) on delete cascade, -- feed for the subscription + url text, -- URL of article + title text collate nocase, -- article title + author text collate nocase, -- author's name + published text, -- time of original publication + edited text, -- time of last edit by author + modified text not null default CURRENT_TIMESTAMP, -- time when article was last modified in database + content text, -- content, as (X)HTML + guid text, -- GUID + url_title_hash text not null, -- hash of URL + title; used when checking for updates and for identification if there is no guid. + url_content_hash text not null, -- hash of URL + content, enclosure URL, & content type; used when checking for updates and for identification if there is no guid. + title_content_hash text not null -- hash of title + content, enclosure URL, & content type; used when checking for updates and for identification if there is no guid. ); insert into arsse_articles select * from arsse_articles_old; drop table arsse_articles_old; alter table arsse_categories rename to arsse_categories_old; create table arsse_categories( - article integer not null references arsse_articles(id) on delete cascade, - name text collate nocase +-- author categories associated with newsfeed entries +-- these are not user-modifiable + article integer not null references arsse_articles(id) on delete cascade, -- article associated with the category + name text collate nocase -- freeform name of the category ); insert into arsse_categories select * from arsse_categories_old; drop table arsse_categories_old; @@ -97,10 +109,11 @@ drop table arsse_categories_old; alter table arsse_labels rename to arsse_labels_old; create table arsse_labels ( - id integer primary key, - owner text not null references arsse_users(id) on delete cascade on update cascade, - name text not null collate nocase, - modified text not null default CURRENT_TIMESTAMP, +-- user-defined article labels for Tiny Tiny RSS + id integer primary key, -- numeric ID + owner text not null references arsse_users(id) on delete cascade on update cascade, -- owning user + name text not null collate nocase, -- label text + modified text not null default CURRENT_TIMESTAMP, -- time at which the label was last modified unique(owner,name) ); insert into arsse_labels select * from arsse_labels_old; @@ -108,4 +121,4 @@ drop table arsse_labels_old; -- set version marker pragma user_version = 3; -update arsse_meta set value = '3' where key = 'schema_version'; \ No newline at end of file +update arsse_meta set value = '3' where key = 'schema_version';