]> git.wh0rd.org - tt-rss.git/blob - schema/ttrss_schema_pgsql.sql
schema: updates for new filter format (bump version to 131)
[tt-rss.git] / schema / ttrss_schema_pgsql.sql
1 drop table if exists ttrss_error_log;
2 drop table if exists ttrss_plugin_storage;
3 drop table if exists ttrss_linked_feeds;
4 drop table if exists ttrss_linked_instances;
5 drop table if exists ttrss_access_keys;
6 drop table if exists ttrss_user_labels2;
7 drop table if exists ttrss_labels2;
8 drop table if exists ttrss_feedbrowser_cache;
9 drop table if exists ttrss_version;
10 drop table if exists ttrss_labels;
11 drop table if exists ttrss_filters2_rules;
12 drop table if exists ttrss_filters2_actions;
13 drop table if exists ttrss_filters2;
14 drop table if exists ttrss_filters;
15 drop table if exists ttrss_filter_types;
16 drop table if exists ttrss_filter_actions;
17 drop table if exists ttrss_user_prefs;
18 drop table if exists ttrss_prefs;
19 drop table if exists ttrss_prefs_types;
20 drop table if exists ttrss_prefs_sections;
21 drop table if exists ttrss_tags;
22 drop table if exists ttrss_enclosures;
23 drop table if exists ttrss_settings_profiles;
24 drop table if exists ttrss_entry_comments;
25 drop table if exists ttrss_user_entries;
26 drop table if exists ttrss_entries;
27 drop table if exists ttrss_scheduled_updates;
28 drop table if exists ttrss_counters_cache;
29 drop table if exists ttrss_cat_counters_cache;
30 drop table if exists ttrss_archived_feeds;
31 drop table if exists ttrss_feeds;
32 drop table if exists ttrss_feed_categories;
33 drop table if exists ttrss_users;
34 drop table if exists ttrss_themes;
35 drop table if exists ttrss_sessions;
36 drop function if exists SUBSTRING_FOR_DATE(timestamp, int, int);
37
38 begin;
39
40 create table ttrss_users (id serial not null primary key,
41 login varchar(120) not null unique,
42 pwd_hash varchar(250) not null,
43 last_login timestamp default null,
44 access_level integer not null default 0,
45 email varchar(250) not null default '',
46 full_name varchar(250) not null default '',
47 email_digest boolean not null default false,
48 last_digest_sent timestamp default null,
49 salt varchar(250) not null default '',
50 twitter_oauth text default null,
51 otp_enabled boolean not null default false,
52 resetpass_token varchar(250) default null,
53 created timestamp default null);
54
55 insert into ttrss_users (login,pwd_hash,access_level) values ('admin',
56 'SHA1:5baa61e4c9b93f3f0682250b6cf8331b7ee68fd8', 10);
57
58 create table ttrss_feed_categories(id serial not null primary key,
59 owner_uid integer not null references ttrss_users(id) on delete cascade,
60 collapsed boolean not null default false,
61 order_id integer not null default 0,
62 view_settings varchar(250) not null default '',
63 parent_cat integer references ttrss_feed_categories(id) on delete set null,
64 title varchar(200) not null);
65
66 create table ttrss_feeds (id serial not null primary key,
67 owner_uid integer not null references ttrss_users(id) on delete cascade,
68 title varchar(200) not null,
69 cat_id integer default null references ttrss_feed_categories(id) on delete set null,
70 feed_url text not null,
71 icon_url varchar(250) not null default '',
72 update_interval integer not null default 0,
73 purge_interval integer not null default 0,
74 last_updated timestamp default null,
75 last_error text not null default '',
76 favicon_avg_color varchar(11) default null,
77 site_url varchar(250) not null default '',
78 auth_login varchar(250) not null default '',
79 parent_feed integer default null references ttrss_feeds(id) on delete set null,
80 private boolean not null default false,
81 auth_pass varchar(250) not null default '',
82 hidden boolean not null default false,
83 include_in_digest boolean not null default true,
84 rtl_content boolean not null default false,
85 cache_images boolean not null default false,
86 hide_images boolean not null default false,
87 cache_content boolean not null default false,
88 last_viewed timestamp default null,
89 last_update_started timestamp default null,
90 update_method integer not null default 0,
91 always_display_enclosures boolean not null default false,
92 order_id integer not null default 0,
93 mark_unread_on_update boolean not null default false,
94 update_on_checksum_change boolean not null default false,
95 strip_images boolean not null default false,
96 view_settings varchar(250) not null default '',
97 pubsub_state integer not null default 0,
98 favicon_last_checked timestamp default null,
99 feed_language varchar(100) not null default '',
100 auth_pass_encrypted boolean not null default false);
101
102 create index ttrss_feeds_owner_uid_index on ttrss_feeds(owner_uid);
103 create index ttrss_feeds_cat_id_idx on ttrss_feeds(cat_id);
104
105 insert into ttrss_feeds (owner_uid, title, feed_url) values
106 (1, 'Tiny Tiny RSS: Forum', 'http://tt-rss.org/forum/rss.php');
107
108 create table ttrss_archived_feeds (id integer not null primary key,
109 owner_uid integer not null references ttrss_users(id) on delete cascade,
110 title varchar(200) not null,
111 feed_url text not null,
112 site_url varchar(250) not null default '');
113
114 create table ttrss_counters_cache (
115 feed_id integer not null,
116 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
117 updated timestamp not null,
118 value integer not null default 0);
119
120 create index ttrss_counters_cache_feed_id_idx on ttrss_counters_cache(feed_id);
121 create index ttrss_counters_cache_owner_uid_idx on ttrss_counters_cache(owner_uid);
122 create index ttrss_counters_cache_value_idx on ttrss_counters_cache(value);
123
124 create table ttrss_cat_counters_cache (
125 feed_id integer not null,
126 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
127 updated timestamp not null,
128 value integer not null default 0);
129
130 create index ttrss_cat_counters_cache_owner_uid_idx on ttrss_cat_counters_cache(owner_uid);
131
132 create table ttrss_entries (id serial not null primary key,
133 title text not null,
134 guid text not null unique,
135 link text not null,
136 updated timestamp not null,
137 content text not null,
138 content_hash varchar(250) not null,
139 cached_content text,
140 no_orig_date boolean not null default false,
141 date_entered timestamp not null,
142 date_updated timestamp not null,
143 num_comments integer not null default 0,
144 comments varchar(250) not null default '',
145 plugin_data text,
146 tsvector_combined tsvector,
147 lang varchar(2),
148 author varchar(250) not null default '');
149
150 -- create index ttrss_entries_title_index on ttrss_entries(title);
151 create index ttrss_entries_date_entered_index on ttrss_entries(date_entered);
152 create index ttrss_entries_updated_idx on ttrss_entries(updated);
153 create index ttrss_entries_tsvector_combined_idx on ttrss_entries using gin(tsvector_combined);
154
155 create table ttrss_user_entries (
156 int_id serial not null primary key,
157 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
158 uuid varchar(200) not null,
159 feed_id int references ttrss_feeds(id) ON DELETE CASCADE,
160 orig_feed_id integer references ttrss_archived_feeds(id) ON DELETE SET NULL,
161 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
162 marked boolean not null default false,
163 published boolean not null default false,
164 tag_cache text not null,
165 label_cache text not null,
166 last_read timestamp,
167 score int not null default 0,
168 last_marked timestamp,
169 last_published timestamp,
170 note text,
171 unread boolean not null default true);
172
173 -- create index ttrss_user_entries_feed_id_index on ttrss_user_entries(feed_id);
174 create index ttrss_user_entries_owner_uid_index on ttrss_user_entries(owner_uid);
175 create index ttrss_user_entries_ref_id_index on ttrss_user_entries(ref_id);
176 create index ttrss_user_entries_feed_id on ttrss_user_entries(feed_id);
177 create index ttrss_user_entries_unread_idx on ttrss_user_entries(unread);
178
179 create table ttrss_entry_comments (id serial not null primary key,
180 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
181 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
182 private boolean not null default false,
183 date_entered timestamp not null);
184
185 create index ttrss_entry_comments_ref_id_index on ttrss_entry_comments(ref_id);
186 -- create index ttrss_entry_comments_owner_uid_index on ttrss_entry_comments(owner_uid);
187
188 create table ttrss_filter_types (id integer not null primary key,
189 name varchar(120) unique not null,
190 description varchar(250) not null unique);
191
192 insert into ttrss_filter_types (id,name,description) values (1, 'title', 'Title');
193 insert into ttrss_filter_types (id,name,description) values (2, 'content', 'Content');
194 insert into ttrss_filter_types (id,name,description) values (3, 'both',
195 'Title or Content');
196 insert into ttrss_filter_types (id,name,description) values (4, 'link',
197 'Link');
198 insert into ttrss_filter_types (id,name,description) values (5, 'date',
199 'Article Date');
200 insert into ttrss_filter_types (id,name,description) values (6, 'author', 'Author');
201 insert into ttrss_filter_types (id,name,description) values (7, 'tag', 'Article Tags');
202
203 create table ttrss_filter_actions (id integer not null primary key,
204 name varchar(120) unique not null,
205 description varchar(250) not null unique);
206
207 insert into ttrss_filter_actions (id,name,description) values (1, 'filter',
208 'Delete article');
209
210 insert into ttrss_filter_actions (id,name,description) values (2, 'catchup',
211 'Mark as read');
212
213 insert into ttrss_filter_actions (id,name,description) values (3, 'mark',
214 'Set starred');
215
216 insert into ttrss_filter_actions (id,name,description) values (4, 'tag',
217 'Assign tags');
218
219 insert into ttrss_filter_actions (id,name,description) values (5, 'publish',
220 'Publish article');
221
222 insert into ttrss_filter_actions (id,name,description) values (6, 'score',
223 'Modify score');
224
225 insert into ttrss_filter_actions (id,name,description) values (7, 'label',
226 'Assign label');
227
228 insert into ttrss_filter_actions (id,name,description) values (8, 'stop',
229 'Stop / Do nothing');
230
231 insert into ttrss_filter_actions (id,name,description) values (9, 'plugin',
232 'Invoke plugin');
233
234 create table ttrss_filters2(id serial not null primary key,
235 owner_uid integer not null references ttrss_users(id) on delete cascade,
236 match_any_rule boolean not null default false,
237 inverse boolean not null default false,
238 title varchar(250) not null default '',
239 order_id integer not null default 0,
240 enabled boolean not null default true);
241
242 create table ttrss_filters2_rules(id serial not null primary key,
243 filter_id integer not null references ttrss_filters2(id) on delete cascade,
244 reg_exp varchar(250) not null,
245 inverse boolean not null default false,
246 filter_type integer not null references ttrss_filter_types(id),
247 feed_id integer references ttrss_feeds(id) on delete cascade default null,
248 cat_id integer references ttrss_feed_categories(id) on delete cascade default null,
249 match_on text,
250 cat_filter boolean not null default false);
251
252 create table ttrss_filters2_actions(id serial not null primary key,
253 filter_id integer not null references ttrss_filters2(id) on delete cascade,
254 action_id integer not null default 1 references ttrss_filter_actions(id) on delete cascade,
255 action_param varchar(250) not null default '');
256
257 create table ttrss_tags (id serial not null primary key,
258 tag_name varchar(250) not null,
259 owner_uid integer not null references ttrss_users(id) on delete cascade,
260 post_int_id integer references ttrss_user_entries(int_id) ON DELETE CASCADE not null);
261
262 create index ttrss_tags_owner_uid_index on ttrss_tags(owner_uid);
263 create index ttrss_tags_post_int_id_idx on ttrss_tags(post_int_id);
264
265 create table ttrss_version (schema_version int not null);
266
267 insert into ttrss_version values (131);
268
269 create table ttrss_enclosures (id serial not null primary key,
270 content_url text not null,
271 content_type varchar(250) not null,
272 title text not null,
273 duration text not null,
274 width integer not null default 0,
275 height integer not null default 0,
276 post_id integer references ttrss_entries(id) ON DELETE cascade NOT NULL);
277
278 create index ttrss_enclosures_post_id_idx on ttrss_enclosures(post_id);
279
280 create table ttrss_settings_profiles(id serial not null primary key,
281 title varchar(250) not null,
282 owner_uid integer not null references ttrss_users(id) on delete cascade);
283
284 create table ttrss_prefs_types (id integer not null primary key,
285 type_name varchar(100) not null);
286
287 insert into ttrss_prefs_types (id, type_name) values (1, 'bool');
288 insert into ttrss_prefs_types (id, type_name) values (2, 'string');
289 insert into ttrss_prefs_types (id, type_name) values (3, 'integer');
290
291 create table ttrss_prefs_sections (id integer not null primary key,
292 order_id integer not null,
293 section_name varchar(100) not null);
294
295 insert into ttrss_prefs_sections (id, section_name, order_id) values (1, 'General', 0);
296 insert into ttrss_prefs_sections (id, section_name, order_id) values (2, 'Interface', 1);
297 insert into ttrss_prefs_sections (id, section_name, order_id) values (3, 'Advanced', 3);
298 insert into ttrss_prefs_sections (id, section_name, order_id) values (4, 'Digest', 2);
299
300 create table ttrss_prefs (pref_name varchar(250) not null primary key,
301 type_id integer not null references ttrss_prefs_types(id),
302 section_id integer not null default 1 references ttrss_prefs_sections(id),
303 access_level integer not null default 0,
304 def_value text not null);
305
306 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('PURGE_OLD_DAYS', 3, '60', 1);
307 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DEFAULT_UPDATE_INTERVAL', 3, '30', 1);
308 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DEFAULT_ARTICLE_LIMIT', 3, '30', 2);
309 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('ALLOW_DUPLICATE_POSTS', 1, 'false', 1);
310 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('ENABLE_FEED_CATS', 1, 'true', 2);
311 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('SHOW_CONTENT_PREVIEW', 1, 'true', 2);
312 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('SHORT_DATE_FORMAT', 2, 'M d, G:i', 3);
313 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('LONG_DATE_FORMAT', 2, 'D, M d Y - G:i', 3);
314 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('COMBINED_DISPLAY_MODE', 1, 'true', 2);
315 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('HIDE_READ_FEEDS', 1, 'false', 2);
316 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('ON_CATCHUP_SHOW_NEXT_FEED', 1, 'false', 2);
317 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('FEEDS_SORT_BY_UNREAD', 1, 'false', 2);
318 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('REVERSE_HEADLINES', 1, 'false', 2);
319 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DIGEST_ENABLE', 1, 'false', 4);
320 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('CONFIRM_FEED_CATCHUP', 1, 'true', 2);
321 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('CDM_AUTO_CATCHUP', 1, 'false', 2);
322 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_DEFAULT_VIEW_MODE', 2, 'adaptive', 1);
323 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_DEFAULT_VIEW_LIMIT', 3, '30', 1);
324 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_PREFS_ACTIVE_TAB', 2, '', 1);
325 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('STRIP_UNSAFE_TAGS', 1, 'true', 3);
326 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('BLACKLISTED_TAGS', 2, 'main, generic, misc, uncategorized, blog, blogroll, general, news', 3);
327 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('FRESH_ARTICLE_MAX_AGE', 3, '24', 2);
328 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DIGEST_CATCHUP', 1, 'false', 4);
329 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('CDM_EXPANDED', 1, 'true', 2);
330 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('PURGE_UNREAD_ARTICLES', 1, 'true', 3);
331 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('HIDE_READ_SHOWS_SPECIAL', 1, 'true', 2);
332 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('VFEED_GROUP_BY_FEED', 1, 'false', 2);
333 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('STRIP_IMAGES', 1, 'false', 2);
334 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_DEFAULT_VIEW_ORDER_BY', 2, 'default', 1);
335 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('ENABLE_API_ACCESS', 1, 'false', 1);
336 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_COLLAPSED_SPECIAL', 1, 'false', 1);
337 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_COLLAPSED_LABELS', 1, 'false', 1);
338 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_COLLAPSED_UNCAT', 1, 'false', 1);
339 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_COLLAPSED_FEEDLIST', 1, 'false', 1);
340 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_ENABLE_CATS', 1, 'false', 1);
341 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_SHOW_IMAGES', 1, 'false', 1);
342 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_HIDE_READ', 1, 'false', 1);
343 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_SORT_FEEDS_UNREAD', 1, 'false', 1);
344 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_THEME_ID', 2, '0', 1);
345 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('USER_TIMEZONE', 2, 'Automatic', 1);
346 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('USER_STYLESHEET', 2, '', 2);
347 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('SORT_HEADLINES_BY_FEED_DATE', 1, 'false', 2);
348 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_BROWSE_CATS', 1, 'true', 1);
349 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('SSL_CERT_SERIAL', 2, '', 3);
350 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DIGEST_PREFERRED_TIME', 2, '00:00', 4);
351 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_PREFS_SHOW_EMPTY_CATS', 1, 'false', 1);
352 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_DEFAULT_INCLUDE_CHILDREN', 1, 'false', 1);
353 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('AUTO_ASSIGN_LABELS', 1, 'false', 3);
354 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_ENABLED_PLUGINS', 2, '', 1);
355 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_REVERSE_HEADLINES', 1, 'false', 1);
356 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('USER_CSS_THEME', 2, '', 2);
357 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('USER_LANGUAGE', 2, '', 2);
358
359 update ttrss_prefs set access_level = 1 where pref_name in ('ON_CATCHUP_SHOW_NEXT_FEED',
360 'SORT_HEADLINES_BY_FEED_DATE',
361 'VFEED_GROUP_BY_FEED',
362 'FRESH_ARTICLE_MAX_AGE',
363 'CDM_EXPANDED',
364 'SHOW_CONTENT_PREVIEW',
365 'AUTO_ASSIGN_LABELS',
366 'HIDE_READ_SHOWS_SPECIAL');
367
368 create table ttrss_user_prefs (
369 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
370 pref_name varchar(250) not null references ttrss_prefs(pref_name) ON DELETE CASCADE,
371 profile integer references ttrss_settings_profiles(id) ON DELETE CASCADE,
372 value text not null);
373
374 create index ttrss_user_prefs_owner_uid_index on ttrss_user_prefs(owner_uid);
375 create index ttrss_user_prefs_pref_name_idx on ttrss_user_prefs(pref_name);
376 -- create index ttrss_user_prefs_value_index on ttrss_user_prefs(value);
377
378 create table ttrss_sessions (id varchar(250) not null primary key,
379 data text,
380 expire integer not null);
381
382 create index ttrss_sessions_expire_index on ttrss_sessions(expire);
383
384 create function SUBSTRING_FOR_DATE(timestamp, int, int) RETURNS text AS 'SELECT SUBSTRING(CAST($1 AS text), $2, $3)' LANGUAGE 'sql';
385
386 create table ttrss_feedbrowser_cache (
387 feed_url text not null primary key,
388 title text not null,
389 site_url text not null,
390 subscribers integer not null);
391
392 create table ttrss_labels2 (id serial not null primary key,
393 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
394 fg_color varchar(15) not null default '',
395 bg_color varchar(15) not null default '',
396 caption varchar(250) not null
397 );
398
399 create table ttrss_user_labels2 (
400 label_id integer not null references ttrss_labels2(id) ON DELETE CASCADE,
401 article_id integer not null references ttrss_entries(id) ON DELETE CASCADE
402 );
403
404 create table ttrss_access_keys (id serial not null primary key,
405 access_key varchar(250) not null,
406 feed_id varchar(250) not null,
407 is_cat boolean not null default false,
408 owner_uid integer not null references ttrss_users(id) on delete cascade);
409
410 create table ttrss_linked_instances (id serial not null primary key,
411 last_connected timestamp not null,
412 last_status_in integer not null,
413 last_status_out integer not null,
414 access_key varchar(250) not null unique,
415 access_url text not null);
416
417 create table ttrss_linked_feeds (
418 feed_url text not null,
419 site_url text not null,
420 title text not null,
421 created timestamp not null,
422 updated timestamp not null,
423 instance_id integer not null references ttrss_linked_instances(id) ON DELETE CASCADE,
424 subscribers integer not null);
425
426 create table ttrss_plugin_storage (
427 id serial not null primary key,
428 name varchar(100) not null,
429 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
430 content text not null);
431
432 create table ttrss_error_log(
433 id serial not null primary key,
434 owner_uid integer references ttrss_users(id) ON DELETE SET NULL,
435 errno integer not null,
436 errstr text not null,
437 filename text not null,
438 lineno integer not null,
439 context text not null,
440 created_at timestamp not null);
441
442 commit;