Browse Source

Use correct SQLite chema change procedure; version bump

J. King 1 month ago
parent
commit
05aadfe7c7
6 changed files with 41 additions and 42 deletions
  1. 1
    0
      CHANGELOG
  2. 1
    1
      lib/Arsse.php
  3. 0
    2
      lib/Db/SQLite3/Driver.php
  4. 7
    7
      sql/SQLite3/1.sql
  5. 28
    28
      sql/SQLite3/2.sql
  6. 4
    4
      sql/SQLite3/3.sql

+ 1
- 0
CHANGELOG View File

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

+ 1
- 1
lib/Arsse.php View File

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

+ 0
- 2
lib/Db/SQLite3/Driver.php View File

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

+ 7
- 7
sql/SQLite3/1.sql View File

@@ -2,7 +2,7 @@
2 2
 -- Copyright 2017 J. King, Dustin Wilson et al.
3 3
 -- See LICENSE and AUTHORS files for details
4 4
 
5
-create table arsse_sessions (
5
+create table arsse_sessions(
6 6
 -- sessions for Tiny Tiny RSS (and possibly others)
7 7
     id text primary key,                                                                    -- UUID of session
8 8
     created text not null default CURRENT_TIMESTAMP,                                        -- Session start timestamp
@@ -10,7 +10,7 @@ create table arsse_sessions (
10 10
     user text not null references arsse_users(id) on delete cascade on update cascade       -- user associated with the session
11 11
 ) without rowid;
12 12
 
13
-create table arsse_labels (
13
+create table arsse_labels(
14 14
 -- user-defined article labels for Tiny Tiny RSS
15 15
     id integer primary key,                                                                 -- numeric ID
16 16
     owner text not null references arsse_users(id) on delete cascade on update cascade,     -- owning user
@@ -19,7 +19,7 @@ create table arsse_labels (
19 19
     unique(owner,name)
20 20
 );
21 21
 
22
-create table arsse_label_members (
22
+create table arsse_label_members(
23 23
 -- uabels assignments for articles
24 24
     label integer not null references arsse_labels(id) on delete cascade,                   -- label ID associated to an article; label IDs belong to a user
25 25
     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 (
32 32
 -- alter marks table to add Tiny Tiny RSS' notes
33 33
 -- SQLite has limited ALTER TABLE support, so the table must be re-created
34 34
 -- and its data re-entered; other database systems have a much simpler prodecure
35
-alter table arsse_marks rename to arsse_marks_old;
36
-create table arsse_marks(
35
+create table arsse_marks_new(
37 36
 -- users' actions on newsfeed entries
38 37
     article integer not null references arsse_articles(id) on delete cascade,                               -- article associated with the marks
39 38
     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(
43 42
     note text not null default '',                                                                          -- Tiny Tiny RSS freeform user note
44 43
     primary key(article,subscription)                                                                       -- no more than one mark-set per article per user
45 44
 );
46
-insert into arsse_marks(article,subscription,read,starred,modified) select article,subscription,read,starred,modified from arsse_marks_old;
47
-drop table arsse_marks_old;
45
+insert into arsse_marks_new(article,subscription,read,starred,modified) select article,subscription,read,starred,modified from arsse_marks;
46
+drop table arsse_marks;
47
+alter table arsse_marks_new rename to arsse_marks;
48 48
 
49 49
 -- set version marker
50 50
 pragma user_version = 2;

+ 28
- 28
sql/SQLite3/2.sql View File

@@ -5,8 +5,7 @@
5 5
 -- Correct collation sequences in order for various things to sort case-insensitively
6 6
 -- SQLite has limited ALTER TABLE support, so the tables must be re-created
7 7
 -- and their data re-entered; other database systems have a much simpler prodecure
8
-alter table arsse_users rename to arsse_users_old;
9
-create table arsse_users(
8
+create table arsse_users_new(
10 9
 -- users
11 10
     id text primary key not null collate nocase,                                                            -- user id
12 11
     password text,                                                                                          -- password, salted and hashed; if using external authentication this would be blank
@@ -16,11 +15,11 @@ create table arsse_users(
16 15
     admin boolean default 0,                                                                                -- whether the user is a member of the special "admin" group
17 16
     rights integer not null default 0                                                                       -- temporary admin-rights marker FIXME: remove reliance on this
18 17
 );
19
-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;
20
-drop table arsse_users_old;
18
+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;
19
+drop table arsse_users;
20
+alter table arsse_users_new rename to arsse_users;
21 21
 
22
-alter table arsse_folders rename to arsse_folders_old;
23
-create table arsse_folders(
22
+create table arsse_folders_new(
24 23
 -- folders, used by NextCloud News and Tiny Tiny RSS
25 24
 -- feed subscriptions may belong to at most one folder;
26 25
 -- in Tiny Tiny RSS folders may nest
@@ -31,11 +30,11 @@ create table arsse_folders(
31 30
     modified text not null default CURRENT_TIMESTAMP,                                                       -- time at which the folder itself (not its contents) was changed; not currently used
32 31
     unique(owner,name,parent)                                                                               -- cannot have multiple folders with the same name under the same parent for the same owner
33 32
 );
34
-insert into arsse_folders select * from arsse_folders_old;
35
-drop table arsse_folders_old;
33
+insert into arsse_folders_new select * from arsse_folders;
34
+drop table arsse_folders;
35
+alter table arsse_folders_new rename to arsse_folders;
36 36
 
37
-alter table arsse_feeds rename to arsse_feeds_old;
38
-create table arsse_feeds(
37
+create table arsse_feeds_new(
39 38
 -- newsfeeds, deduplicated
40 39
 -- users have subscriptions to these feeds in another table
41 40
     id integer primary key,                                                                                 -- sequence number
@@ -56,11 +55,11 @@ create table arsse_feeds(
56 55
     scrape boolean not null default 0,                                                                      -- whether to use picoFeed's content scraper with this feed
57 56
     unique(url,username,password)                                                                           -- a URL with particular credentials should only appear once
58 57
 );
59
-insert into arsse_feeds select * from arsse_feeds_old;
60
-drop table arsse_feeds_old;
58
+insert into arsse_feeds_new select * from arsse_feeds;
59
+drop table arsse_feeds;
60
+alter table arsse_feeds_new rename to arsse_feeds;
61 61
 
62
-alter table arsse_subscriptions rename to arsse_subscriptions_old;
63
-create table arsse_subscriptions(
62
+create table arsse_subscriptions_new(
64 63
 -- users' subscriptions to newsfeeds, with settings
65 64
     id integer primary key,                                                                                 -- sequence number
66 65
     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(
73 72
     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
74 73
     unique(owner,feed)                                                                                      -- a given feed should only appear once for a given owner
75 74
 );
76
-insert into arsse_subscriptions select * from arsse_subscriptions_old;
77
-drop table arsse_subscriptions_old;
75
+insert into arsse_subscriptions_new select * from arsse_subscriptions;
76
+drop table arsse_subscriptions;
77
+alter table arsse_subscriptions_new rename to arsse_subscriptions;
78 78
 
79
-alter table arsse_articles rename to arsse_articles_old;
80
-create table arsse_articles(
79
+create table arsse_articles_new(
81 80
 -- entries in newsfeeds
82 81
     id integer primary key,                                                                                 -- sequence number
83 82
     feed integer not null references arsse_feeds(id) on delete cascade,                                     -- feed for the subscription
@@ -93,22 +92,22 @@ create table arsse_articles(
93 92
     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.
94 93
     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.
95 94
 );
96
-insert into arsse_articles select * from arsse_articles_old;
97
-drop table arsse_articles_old;
95
+insert into arsse_articles_new select * from arsse_articles;
96
+drop table arsse_articles;
97
+alter table arsse_articles_new rename to arsse_articles;
98 98
 
99
-alter table arsse_categories rename to arsse_categories_old;
100
-create table arsse_categories(
99
+create table arsse_categories_new(
101 100
 -- author categories associated with newsfeed entries
102 101
 -- these are not user-modifiable
103 102
     article integer not null references arsse_articles(id) on delete cascade,                               -- article associated with the category
104 103
     name text collate nocase                                                                                -- freeform name of the category
105 104
 );
106
-insert into arsse_categories select * from arsse_categories_old;
107
-drop table arsse_categories_old;
105
+insert into arsse_categories_new select * from arsse_categories;
106
+drop table arsse_categories;
107
+alter table arsse_categories_new rename to arsse_categories;
108 108
 
109 109
 
110
-alter table arsse_labels rename to arsse_labels_old;
111
-create table arsse_labels (
110
+create table arsse_labels_new(
112 111
 -- user-defined article labels for Tiny Tiny RSS
113 112
     id integer primary key,                                                                 -- numeric ID
114 113
     owner text not null references arsse_users(id) on delete cascade on update cascade,     -- owning user
@@ -116,8 +115,9 @@ create table arsse_labels (
116 115
     modified text not null default CURRENT_TIMESTAMP,                                       -- time at which the label was last modified
117 116
     unique(owner,name)
118 117
 );
119
-insert into arsse_labels select * from arsse_labels_old;
120
-drop table arsse_labels_old;
118
+insert into arsse_labels_new select * from arsse_labels;
119
+drop table arsse_labels;
120
+alter table arsse_labels_new rename to arsse_labels;
121 121
 
122 122
 -- set version marker
123 123
 pragma user_version = 3;

+ 4
- 4
sql/SQLite3/3.sql View File

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

Loading…
Cancel
Save