Browse Source

Use correct SQLite chema change procedure; version bump

microsub 0.6.0
J. King 5 years ago
parent
commit
05aadfe7c7
  1. 1
      CHANGELOG
  2. 2
      lib/Arsse.php
  3. 2
      lib/Db/SQLite3/Driver.php
  4. 14
      sql/SQLite3/1.sql
  5. 56
      sql/SQLite3/2.sql
  6. 8
      sql/SQLite3/3.sql

1
CHANGELOG

@ -8,6 +8,7 @@ New features:
Bug fixes: Bug fixes:
- Use a general-purpose Unicode collation with SQLite databases - Use a general-purpose Unicode collation with SQLite databases
- Use the correct SQLite schema change procedure for 3.25 and later
Changes: Changes:
- Improve performance of common database queries by 80-90% - Improve performance of common database queries by 80-90%

2
lib/Arsse.php

@ -7,7 +7,7 @@ declare(strict_types=1);
namespace JKingWeb\Arsse; namespace JKingWeb\Arsse;
class Arsse { class Arsse {
const VERSION = "0.5.1"; const VERSION = "0.6.0";
/** @var Lang */ /** @var Lang */
public static $lang; public static $lang;

2
lib/Db/SQLite3/Driver.php

@ -123,14 +123,12 @@ class Driver extends \JKingWeb\Arsse\Db\AbstractDriver {
public function schemaUpdate(int $to, string $basePath = null): bool { public function schemaUpdate(int $to, string $basePath = null): bool {
// turn off foreign keys // turn off foreign keys
$this->exec("PRAGMA foreign_keys = no"); $this->exec("PRAGMA foreign_keys = no");
$this->exec("PRAGMA legacy_alter_table = yes");
// run the generic updater // run the generic updater
try { try {
parent::schemaUpdate($to, $basePath); parent::schemaUpdate($to, $basePath);
} finally { } finally {
// turn foreign keys back on // turn foreign keys back on
$this->exec("PRAGMA foreign_keys = yes"); $this->exec("PRAGMA foreign_keys = yes");
$this->exec("PRAGMA legacy_alter_table = no");
} }
return true; return true;
} }

14
sql/SQLite3/1.sql

@ -2,7 +2,7 @@
-- Copyright 2017 J. King, Dustin Wilson et al. -- Copyright 2017 J. King, Dustin Wilson et al.
-- See LICENSE and AUTHORS files for details -- See LICENSE and AUTHORS files for details
create table arsse_sessions ( create table arsse_sessions(
-- sessions for Tiny Tiny RSS (and possibly others) -- sessions for Tiny Tiny RSS (and possibly others)
id text primary key, -- UUID of session id text primary key, -- UUID of session
created text not null default CURRENT_TIMESTAMP, -- Session start timestamp created text not null default CURRENT_TIMESTAMP, -- Session start timestamp
@ -10,7 +10,7 @@ create table arsse_sessions (
user text not null references arsse_users(id) on delete cascade on update cascade -- user associated with the session user text not null references arsse_users(id) on delete cascade on update cascade -- user associated with the session
) without rowid; ) without rowid;
create table arsse_labels ( create table arsse_labels(
-- user-defined article labels for Tiny Tiny RSS -- user-defined article labels for Tiny Tiny RSS
id integer primary key, -- numeric ID id integer primary key, -- numeric ID
owner text not null references arsse_users(id) on delete cascade on update cascade, -- owning user owner text not null references arsse_users(id) on delete cascade on update cascade, -- owning user
@ -19,7 +19,7 @@ create table arsse_labels (
unique(owner,name) unique(owner,name)
); );
create table arsse_label_members ( create table arsse_label_members(
-- uabels assignments for articles -- 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 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 article integer not null references arsse_articles(id) on delete cascade, -- article associated to a label
@ -32,8 +32,7 @@ create table arsse_label_members (
-- alter marks table to add Tiny Tiny RSS' notes -- alter marks table to add Tiny Tiny RSS' notes
-- SQLite has limited ALTER TABLE support, so the table must be re-created -- 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 -- 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_new(
create table arsse_marks(
-- users' actions on newsfeed entries -- users' actions on newsfeed entries
article integer not null references arsse_articles(id) on delete cascade, -- article associated with the marks 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 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
@ -43,8 +42,9 @@ create table arsse_marks(
note text not null default '', -- Tiny Tiny RSS freeform user note 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 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; insert into arsse_marks_new(article,subscription,read,starred,modified) select article,subscription,read,starred,modified from arsse_marks;
drop table arsse_marks_old; drop table arsse_marks;
alter table arsse_marks_new rename to arsse_marks;
-- set version marker -- set version marker
pragma user_version = 2; pragma user_version = 2;

56
sql/SQLite3/2.sql

@ -5,8 +5,7 @@
-- Correct collation sequences in order for various things to sort case-insensitively -- 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 -- 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 -- 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_new(
create table arsse_users(
-- users -- users
id text primary key not null collate nocase, -- user id id text primary key not null collate nocase, -- user id
password text, -- password, salted and hashed; if using external authentication this would be blank password text, -- password, salted and hashed; if using external authentication this would be blank
@ -16,11 +15,11 @@ create table arsse_users(
admin boolean default 0, -- whether the user is a member of the special "admin" group 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 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; insert into arsse_users_new(id,password,name,avatar_type,avatar_data,admin,rights) select id,password,name,avatar_type,avatar_data,admin,rights from arsse_users;
drop table arsse_users_old; drop table arsse_users;
alter table arsse_users_new rename to arsse_users;
alter table arsse_folders rename to arsse_folders_old; create table arsse_folders_new(
create table arsse_folders(
-- folders, used by NextCloud News and Tiny Tiny RSS -- folders, used by NextCloud News and Tiny Tiny RSS
-- feed subscriptions may belong to at most one folder; -- feed subscriptions may belong to at most one folder;
-- in Tiny Tiny RSS folders may nest -- in Tiny Tiny RSS folders may nest
@ -31,11 +30,11 @@ create table arsse_folders(
modified text not null default CURRENT_TIMESTAMP, -- time at which the folder itself (not its contents) was changed; not currently used 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 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; insert into arsse_folders_new select * from arsse_folders;
drop table arsse_folders_old; drop table arsse_folders;
alter table arsse_folders_new rename to arsse_folders;
alter table arsse_feeds rename to arsse_feeds_old; create table arsse_feeds_new(
create table arsse_feeds(
-- newsfeeds, deduplicated -- newsfeeds, deduplicated
-- users have subscriptions to these feeds in another table -- users have subscriptions to these feeds in another table
id integer primary key, -- sequence number id integer primary key, -- sequence number
@ -56,11 +55,11 @@ create table arsse_feeds(
scrape boolean not null default 0, -- whether to use picoFeed's content scraper with this feed 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 unique(url,username,password) -- a URL with particular credentials should only appear once
); );
insert into arsse_feeds select * from arsse_feeds_old; insert into arsse_feeds_new select * from arsse_feeds;
drop table arsse_feeds_old; drop table arsse_feeds;
alter table arsse_feeds_new rename to arsse_feeds;
alter table arsse_subscriptions rename to arsse_subscriptions_old; create table arsse_subscriptions_new(
create table arsse_subscriptions(
-- users' subscriptions to newsfeeds, with settings -- users' subscriptions to newsfeeds, with settings
id integer primary key, -- sequence number id integer primary key, -- sequence number
owner text not null references arsse_users(id) on delete cascade on update cascade, -- owner of subscription owner text not null references arsse_users(id) on delete cascade on update cascade, -- owner of subscription
@ -73,11 +72,11 @@ create table arsse_subscriptions(
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 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 unique(owner,feed) -- a given feed should only appear once for a given owner
); );
insert into arsse_subscriptions select * from arsse_subscriptions_old; insert into arsse_subscriptions_new select * from arsse_subscriptions;
drop table arsse_subscriptions_old; drop table arsse_subscriptions;
alter table arsse_subscriptions_new rename to arsse_subscriptions;
alter table arsse_articles rename to arsse_articles_old; create table arsse_articles_new(
create table arsse_articles(
-- entries in newsfeeds -- entries in newsfeeds
id integer primary key, -- sequence number id integer primary key, -- sequence number
feed integer not null references arsse_feeds(id) on delete cascade, -- feed for the subscription feed integer not null references arsse_feeds(id) on delete cascade, -- feed for the subscription
@ -93,22 +92,22 @@ create table arsse_articles(
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. 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. 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; insert into arsse_articles_new select * from arsse_articles;
drop table arsse_articles_old; drop table arsse_articles;
alter table arsse_articles_new rename to arsse_articles;
alter table arsse_categories rename to arsse_categories_old; create table arsse_categories_new(
create table arsse_categories(
-- author categories associated with newsfeed entries -- author categories associated with newsfeed entries
-- these are not user-modifiable -- these are not user-modifiable
article integer not null references arsse_articles(id) on delete cascade, -- article associated with the category 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 name text collate nocase -- freeform name of the category
); );
insert into arsse_categories select * from arsse_categories_old; insert into arsse_categories_new select * from arsse_categories;
drop table arsse_categories_old; drop table arsse_categories;
alter table arsse_categories_new rename to arsse_categories;
alter table arsse_labels rename to arsse_labels_old; create table arsse_labels_new(
create table arsse_labels (
-- user-defined article labels for Tiny Tiny RSS -- user-defined article labels for Tiny Tiny RSS
id integer primary key, -- numeric ID id integer primary key, -- numeric ID
owner text not null references arsse_users(id) on delete cascade on update cascade, -- owning user owner text not null references arsse_users(id) on delete cascade on update cascade, -- owning user
@ -116,8 +115,9 @@ create table arsse_labels (
modified text not null default CURRENT_TIMESTAMP, -- time at which the label was last modified modified text not null default CURRENT_TIMESTAMP, -- time at which the label was last modified
unique(owner,name) unique(owner,name)
); );
insert into arsse_labels select * from arsse_labels_old; insert into arsse_labels_new select * from arsse_labels;
drop table arsse_labels_old; drop table arsse_labels;
alter table arsse_labels_new rename to arsse_labels;
-- set version marker -- set version marker
pragma user_version = 3; pragma user_version = 3;

8
sql/SQLite3/3.sql

@ -4,8 +4,7 @@
-- allow marks to initially have a null date due to changes in how marks are first created -- allow marks to initially have a null date due to changes in how marks are first created
-- and also add a "touched" column to aid in tracking changes during the course of some transactions -- and also add a "touched" column to aid in tracking changes during the course of some transactions
alter table arsse_marks rename to arsse_marks_old; create table arsse_marks_new(
create table arsse_marks(
-- users' actions on newsfeed entries -- users' actions on newsfeed entries
article integer not null references arsse_articles(id) on delete cascade, -- article associated with the marks 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 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
@ -16,8 +15,9 @@ create table arsse_marks(
touched boolean not null default 0, -- used to indicate a record has been modified during the course of some transactions touched boolean not null default 0, -- used to indicate a record has been modified during the course of some transactions
primary key(article,subscription) -- no more than one mark-set per article per user primary key(article,subscription) -- no more than one mark-set per article per user
); );
insert into arsse_marks select article,subscription,read,starred,modified,note,0 from arsse_marks_old; insert into arsse_marks_new select article,subscription,read,starred,modified,note,0 from arsse_marks;
drop table arsse_marks_old; drop table arsse_marks;
alter table arsse_marks_new rename to arsse_marks;
-- reindex anything which uses the nocase collation sequence; it has been replaced with a Unicode collation -- reindex anything which uses the nocase collation sequence; it has been replaced with a Unicode collation
reindex nocase; reindex nocase;

Loading…
Cancel
Save