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);
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);
55 insert into ttrss_users (login,pwd_hash,access_level) values ('admin',
56 'SHA1:5baa61e4c9b93f3f0682250b6cf8331b7ee68fd8', 10);
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);
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 auth_pass_encrypted boolean not null default false);
101 create index ttrss_feeds_owner_uid_index on ttrss_feeds(owner_uid);
102 create index ttrss_feeds_cat_id_idx on ttrss_feeds(cat_id);
104 insert into ttrss_feeds (owner_uid, title, feed_url) values
105 (1, 'Tiny Tiny RSS: New Releases', 'http://tt-rss.org/releases.rss');
107 insert into ttrss_feeds (owner_uid, title, feed_url) values
108 (1, 'Tiny Tiny RSS: Forum', 'http://tt-rss.org/forum/rss.php');
110 create table ttrss_archived_feeds (id integer not null primary key,
111 owner_uid integer not null references ttrss_users(id) on delete cascade,
112 title varchar(200) not null,
113 feed_url text not null,
114 site_url varchar(250) not null default '');
116 create table ttrss_counters_cache (
117 feed_id integer not null,
118 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
119 updated timestamp not null,
120 value integer not null default 0);
122 create index ttrss_counters_cache_feed_id_idx on ttrss_counters_cache(feed_id);
123 create index ttrss_counters_cache_owner_uid_idx on ttrss_counters_cache(owner_uid);
124 create index ttrss_counters_cache_value_idx on ttrss_counters_cache(value);
126 create table ttrss_cat_counters_cache (
127 feed_id integer not null,
128 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
129 updated timestamp not null,
130 value integer not null default 0);
132 create index ttrss_cat_counters_cache_owner_uid_idx on ttrss_cat_counters_cache(owner_uid);
134 create table ttrss_entries (id serial not null primary key,
136 guid text not null unique,
138 updated timestamp not null,
139 content text not null,
140 content_hash varchar(250) not null,
142 no_orig_date boolean not null default false,
143 date_entered timestamp not null,
144 date_updated timestamp not null,
145 num_comments integer not null default 0,
146 comments varchar(250) not null default '',
149 author varchar(250) not null default '');
151 -- create index ttrss_entries_title_index on ttrss_entries(title);
152 create index ttrss_entries_date_entered_index on ttrss_entries(date_entered);
153 create index ttrss_entries_updated_idx on ttrss_entries(updated);
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,
167 score int not null default 0,
168 last_marked timestamp,
169 last_published timestamp,
171 unread boolean not null default true);
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);
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);
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);
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);
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',
196 insert into ttrss_filter_types (id,name,description) values (4, 'link',
198 insert into ttrss_filter_types (id,name,description) values (5, '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');
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);
207 insert into ttrss_filter_actions (id,name,description) values (1, 'filter',
210 insert into ttrss_filter_actions (id,name,description) values (2, 'catchup',
213 insert into ttrss_filter_actions (id,name,description) values (3, 'mark',
216 insert into ttrss_filter_actions (id,name,description) values (4, 'tag',
219 insert into ttrss_filter_actions (id,name,description) values (5, 'publish',
222 insert into ttrss_filter_actions (id,name,description) values (6, 'score',
225 insert into ttrss_filter_actions (id,name,description) values (7, 'label',
228 insert into ttrss_filter_actions (id,name,description) values (8, 'stop',
229 'Stop / Do nothing');
231 create table ttrss_filters2(id serial not null primary key,
232 owner_uid integer not null references ttrss_users(id) on delete cascade,
233 match_any_rule boolean not null default false,
234 inverse boolean not null default false,
235 title varchar(250) not null default '',
236 order_id integer not null default 0,
237 enabled boolean not null default true);
239 create table ttrss_filters2_rules(id serial not null primary key,
240 filter_id integer not null references ttrss_filters2(id) on delete cascade,
241 reg_exp varchar(250) not null,
242 inverse boolean not null default false,
243 filter_type integer not null references ttrss_filter_types(id),
244 feed_id integer references ttrss_feeds(id) on delete cascade default null,
245 cat_id integer references ttrss_feed_categories(id) on delete cascade default null,
246 cat_filter boolean not null default false);
248 create table ttrss_filters2_actions(id serial not null primary key,
249 filter_id integer not null references ttrss_filters2(id) on delete cascade,
250 action_id integer not null default 1 references ttrss_filter_actions(id) on delete cascade,
251 action_param varchar(250) not null default '');
253 create table ttrss_tags (id serial not null primary key,
254 tag_name varchar(250) not null,
255 owner_uid integer not null references ttrss_users(id) on delete cascade,
256 post_int_id integer references ttrss_user_entries(int_id) ON DELETE CASCADE not null);
258 create index ttrss_tags_owner_uid_index on ttrss_tags(owner_uid);
259 create index ttrss_tags_post_int_id_idx on ttrss_tags(post_int_id);
261 create table ttrss_version (schema_version int not null);
263 insert into ttrss_version values (127);
265 create table ttrss_enclosures (id serial not null primary key,
266 content_url text not null,
267 content_type varchar(250) not null,
269 duration text not null,
270 width integer not null default 0,
271 height integer not null default 0,
272 post_id integer references ttrss_entries(id) ON DELETE cascade NOT NULL);
274 create index ttrss_enclosures_post_id_idx on ttrss_enclosures(post_id);
276 create table ttrss_settings_profiles(id serial not null primary key,
277 title varchar(250) not null,
278 owner_uid integer not null references ttrss_users(id) on delete cascade);
280 create table ttrss_prefs_types (id integer not null primary key,
281 type_name varchar(100) not null);
283 insert into ttrss_prefs_types (id, type_name) values (1, 'bool');
284 insert into ttrss_prefs_types (id, type_name) values (2, 'string');
285 insert into ttrss_prefs_types (id, type_name) values (3, 'integer');
287 create table ttrss_prefs_sections (id integer not null primary key,
288 order_id integer not null,
289 section_name varchar(100) not null);
291 insert into ttrss_prefs_sections (id, section_name, order_id) values (1, 'General', 0);
292 insert into ttrss_prefs_sections (id, section_name, order_id) values (2, 'Interface', 1);
293 insert into ttrss_prefs_sections (id, section_name, order_id) values (3, 'Advanced', 3);
294 insert into ttrss_prefs_sections (id, section_name, order_id) values (4, 'Digest', 2);
296 create table ttrss_prefs (pref_name varchar(250) not null primary key,
297 type_id integer not null references ttrss_prefs_types(id),
298 section_id integer not null default 1 references ttrss_prefs_sections(id),
299 access_level integer not null default 0,
300 def_value text not null);
302 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('PURGE_OLD_DAYS', 3, '60', 1);
303 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DEFAULT_UPDATE_INTERVAL', 3, '30', 1);
304 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DEFAULT_ARTICLE_LIMIT', 3, '30', 2);
305 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('ALLOW_DUPLICATE_POSTS', 1, 'false', 1);
306 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('ENABLE_FEED_CATS', 1, 'true', 2);
307 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('SHOW_CONTENT_PREVIEW', 1, 'true', 2);
308 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('SHORT_DATE_FORMAT', 2, 'M d, G:i', 3);
309 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('LONG_DATE_FORMAT', 2, 'D, M d Y - G:i', 3);
310 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('COMBINED_DISPLAY_MODE', 1, 'true', 2);
311 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('HIDE_READ_FEEDS', 1, 'false', 2);
312 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('ON_CATCHUP_SHOW_NEXT_FEED', 1, 'false', 2);
313 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('FEEDS_SORT_BY_UNREAD', 1, 'false', 2);
314 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('REVERSE_HEADLINES', 1, 'false', 2);
315 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DIGEST_ENABLE', 1, 'false', 4);
316 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('CONFIRM_FEED_CATCHUP', 1, 'true', 2);
317 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('CDM_AUTO_CATCHUP', 1, 'false', 2);
318 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_DEFAULT_VIEW_MODE', 2, 'adaptive', 1);
319 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_DEFAULT_VIEW_LIMIT', 3, '30', 1);
320 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_PREFS_ACTIVE_TAB', 2, '', 1);
321 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('STRIP_UNSAFE_TAGS', 1, 'true', 3);
322 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);
323 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('FRESH_ARTICLE_MAX_AGE', 3, '24', 2);
324 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DIGEST_CATCHUP', 1, 'false', 4);
325 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('CDM_EXPANDED', 1, 'true', 2);
326 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('PURGE_UNREAD_ARTICLES', 1, 'true', 3);
327 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('HIDE_READ_SHOWS_SPECIAL', 1, 'true', 2);
328 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('VFEED_GROUP_BY_FEED', 1, 'false', 2);
329 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('STRIP_IMAGES', 1, 'false', 2);
330 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_DEFAULT_VIEW_ORDER_BY', 2, 'default', 1);
331 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('ENABLE_API_ACCESS', 1, 'false', 1);
332 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_COLLAPSED_SPECIAL', 1, 'false', 1);
333 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_COLLAPSED_LABELS', 1, 'false', 1);
334 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_COLLAPSED_UNCAT', 1, 'false', 1);
335 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_COLLAPSED_FEEDLIST', 1, 'false', 1);
336 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_ENABLE_CATS', 1, 'false', 1);
337 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_SHOW_IMAGES', 1, 'false', 1);
338 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_HIDE_READ', 1, 'false', 1);
339 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_SORT_FEEDS_UNREAD', 1, 'false', 1);
340 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_THEME_ID', 2, '0', 1);
341 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('USER_TIMEZONE', 2, 'Automatic', 1);
342 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('USER_STYLESHEET', 2, '', 2);
343 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('SORT_HEADLINES_BY_FEED_DATE', 1, 'false', 2);
344 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_BROWSE_CATS', 1, 'true', 1);
345 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('SSL_CERT_SERIAL', 2, '', 3);
346 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DIGEST_PREFERRED_TIME', 2, '00:00', 4);
347 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_PREFS_SHOW_EMPTY_CATS', 1, 'false', 1);
348 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_DEFAULT_INCLUDE_CHILDREN', 1, 'false', 1);
349 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('AUTO_ASSIGN_LABELS', 1, 'false', 3);
350 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_ENABLED_PLUGINS', 2, '', 1);
351 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_REVERSE_HEADLINES', 1, 'false', 1);
352 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('USER_CSS_THEME', 2, '', 2);
353 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('USER_LANGUAGE', 2, '', 2);
355 update ttrss_prefs set access_level = 1 where pref_name in ('ON_CATCHUP_SHOW_NEXT_FEED',
356 'SORT_HEADLINES_BY_FEED_DATE',
357 'VFEED_GROUP_BY_FEED',
358 'FRESH_ARTICLE_MAX_AGE',
360 'SHOW_CONTENT_PREVIEW',
361 'AUTO_ASSIGN_LABELS',
362 'HIDE_READ_SHOWS_SPECIAL');
364 create table ttrss_user_prefs (
365 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
366 pref_name varchar(250) not null references ttrss_prefs(pref_name) ON DELETE CASCADE,
367 profile integer references ttrss_settings_profiles(id) ON DELETE CASCADE,
368 value text not null);
370 create index ttrss_user_prefs_owner_uid_index on ttrss_user_prefs(owner_uid);
371 create index ttrss_user_prefs_pref_name_idx on ttrss_user_prefs(pref_name);
372 -- create index ttrss_user_prefs_value_index on ttrss_user_prefs(value);
374 create table ttrss_sessions (id varchar(250) not null primary key,
376 expire integer not null);
378 create index ttrss_sessions_expire_index on ttrss_sessions(expire);
380 create function SUBSTRING_FOR_DATE(timestamp, int, int) RETURNS text AS 'SELECT SUBSTRING(CAST($1 AS text), $2, $3)' LANGUAGE 'sql';
382 create table ttrss_feedbrowser_cache (
383 feed_url text not null primary key,
385 site_url text not null,
386 subscribers integer not null);
388 create table ttrss_labels2 (id serial not null primary key,
389 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
390 fg_color varchar(15) not null default '',
391 bg_color varchar(15) not null default '',
392 caption varchar(250) not null
395 create table ttrss_user_labels2 (
396 label_id integer not null references ttrss_labels2(id) ON DELETE CASCADE,
397 article_id integer not null references ttrss_entries(id) ON DELETE CASCADE
400 create table ttrss_access_keys (id serial not null primary key,
401 access_key varchar(250) not null,
402 feed_id varchar(250) not null,
403 is_cat boolean not null default false,
404 owner_uid integer not null references ttrss_users(id) on delete cascade);
406 create table ttrss_linked_instances (id serial not null primary key,
407 last_connected timestamp not null,
408 last_status_in integer not null,
409 last_status_out integer not null,
410 access_key varchar(250) not null unique,
411 access_url text not null);
413 create table ttrss_linked_feeds (
414 feed_url text not null,
415 site_url text not null,
417 created timestamp not null,
418 updated timestamp not null,
419 instance_id integer not null references ttrss_linked_instances(id) ON DELETE CASCADE,
420 subscribers integer not null);
422 create table ttrss_plugin_storage (
423 id serial not null primary key,
424 name varchar(100) not null,
425 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
426 content text not null);
428 create table ttrss_error_log(
429 id serial not null primary key,
430 owner_uid integer references ttrss_users(id) ON DELETE SET NULL,
431 errno integer not null,
432 errstr text not null,
433 filename text not null,
434 lineno integer not null,
435 context text not null,
436 created_at timestamp not null);