1 drop table if exists ttrss_plugin_storage;
2 drop table if exists ttrss_linked_feeds;
3 drop table if exists ttrss_linked_instances;
4 drop table if exists ttrss_access_keys;
5 drop table if exists ttrss_user_labels2;
6 drop table if exists ttrss_labels2;
7 drop table if exists ttrss_feedbrowser_cache;
8 drop table if exists ttrss_version;
9 drop table if exists ttrss_labels;
10 drop table if exists ttrss_filters2_rules;
11 drop table if exists ttrss_filters2_actions;
12 drop table if exists ttrss_filters2;
13 drop table if exists ttrss_filter_types;
14 drop table if exists ttrss_filter_actions;
15 drop table if exists ttrss_user_prefs;
16 drop table if exists ttrss_prefs;
17 drop table if exists ttrss_prefs_types;
18 drop table if exists ttrss_prefs_sections;
19 drop table if exists ttrss_tags;
20 drop table if exists ttrss_enclosures;
21 drop table if exists ttrss_settings_profiles;
22 drop table if exists ttrss_entry_comments;
23 drop table if exists ttrss_user_entries;
24 drop table if exists ttrss_entries;
25 drop table if exists ttrss_scheduled_updates;
26 drop table if exists ttrss_counters_cache;
27 drop table if exists ttrss_cat_counters_cache;
28 drop table if exists ttrss_archived_feeds;
29 drop table if exists ttrss_feeds;
30 drop table if exists ttrss_feed_categories;
31 drop table if exists ttrss_users;
32 drop table if exists ttrss_themes;
33 drop table if exists ttrss_sessions;
34 drop function if exists SUBSTRING_FOR_DATE(timestamp, int, int);
38 create table ttrss_users (id serial not null primary key,
39 login varchar(120) not null unique,
40 pwd_hash varchar(250) not null,
41 last_login timestamp default null,
42 access_level integer not null default 0,
43 email varchar(250) not null default '',
44 full_name varchar(250) not null default '',
45 email_digest boolean not null default false,
46 last_digest_sent timestamp default null,
47 salt varchar(250) not null default '',
48 twitter_oauth text default null,
49 otp_enabled boolean not null default false,
50 created timestamp default null);
52 insert into ttrss_users (login,pwd_hash,access_level) values ('admin',
53 'SHA1:5baa61e4c9b93f3f0682250b6cf8331b7ee68fd8', 10);
55 create table ttrss_feed_categories(id serial not null primary key,
56 owner_uid integer not null references ttrss_users(id) on delete cascade,
57 collapsed boolean not null default false,
58 order_id integer not null default 0,
59 view_settings varchar(250) not null default '',
60 parent_cat integer references ttrss_feed_categories(id) on delete set null,
61 title varchar(200) not null);
63 create table ttrss_feeds (id serial not null primary key,
64 owner_uid integer not null references ttrss_users(id) on delete cascade,
65 title varchar(200) not null,
66 cat_id integer default null references ttrss_feed_categories(id) on delete set null,
67 feed_url text not null,
68 icon_url varchar(250) not null default '',
69 update_interval integer not null default 0,
70 purge_interval integer not null default 0,
71 last_updated timestamp default null,
72 last_error text not null default '',
73 site_url varchar(250) not null default '',
74 auth_login varchar(250) not null default '',
75 parent_feed integer default null references ttrss_feeds(id) on delete set null,
76 private boolean not null default false,
77 auth_pass varchar(250) not null default '',
78 hidden boolean not null default false,
79 include_in_digest boolean not null default true,
80 rtl_content boolean not null default false,
81 cache_images boolean not null default false,
82 hide_images boolean not null default false,
83 cache_content boolean not null default false,
84 last_viewed timestamp default null,
85 last_update_started timestamp default null,
86 update_method integer not null default 0,
87 always_display_enclosures boolean not null default false,
88 order_id integer not null default 0,
89 mark_unread_on_update boolean not null default false,
90 update_on_checksum_change boolean not null default false,
91 strip_images boolean not null default false,
92 view_settings varchar(250) not null default '',
93 pubsub_state integer not null default 0,
94 favicon_last_checked timestamp default null,
95 auth_pass_encrypted boolean not null default false);
97 create index ttrss_feeds_owner_uid_index on ttrss_feeds(owner_uid);
98 create index ttrss_feeds_cat_id_idx on ttrss_feeds(cat_id);
100 insert into ttrss_feeds (owner_uid, title, feed_url) values
101 (1, 'Tiny Tiny RSS: New Releases', 'http://tt-rss.org/releases.rss');
103 insert into ttrss_feeds (owner_uid, title, feed_url) values
104 (1, 'Tiny Tiny RSS: Forum', 'http://tt-rss.org/forum/rss.php');
106 create table ttrss_archived_feeds (id integer not null primary key,
107 owner_uid integer not null references ttrss_users(id) on delete cascade,
108 title varchar(200) not null,
109 feed_url text not null,
110 site_url varchar(250) not null default '');
112 create table ttrss_counters_cache (
113 feed_id integer not null,
114 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
115 updated timestamp not null,
116 value integer not null default 0);
118 create index ttrss_counters_cache_feed_id_idx on ttrss_counters_cache(feed_id);
119 create index ttrss_counters_cache_owner_uid_idx on ttrss_counters_cache(owner_uid);
120 create index ttrss_counters_cache_value_idx on ttrss_counters_cache(value);
122 create table ttrss_cat_counters_cache (
123 feed_id integer not null,
124 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
125 updated timestamp not null,
126 value integer not null default 0);
128 create index ttrss_cat_counters_cache_owner_uid_idx on ttrss_cat_counters_cache(owner_uid);
130 create table ttrss_entries (id serial not null primary key,
132 guid text not null unique,
134 updated timestamp not null,
135 content text not null,
136 content_hash varchar(250) not null,
138 no_orig_date boolean not null default false,
139 date_entered timestamp not null,
140 date_updated timestamp not null,
141 num_comments integer not null default 0,
142 comments varchar(250) not null default '',
144 author varchar(250) not null default '');
146 create index ttrss_entries_guid_index on ttrss_entries(guid);
147 -- create index ttrss_entries_title_index on ttrss_entries(title);
148 create index ttrss_entries_date_entered_index on ttrss_entries(date_entered);
149 create index ttrss_entries_updated_idx on ttrss_entries(updated);
151 create table ttrss_user_entries (
152 int_id serial not null primary key,
153 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
154 uuid varchar(200) not null,
155 feed_id int references ttrss_feeds(id) ON DELETE CASCADE,
156 orig_feed_id integer references ttrss_archived_feeds(id) ON DELETE SET NULL,
157 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
158 marked boolean not null default false,
159 published boolean not null default false,
160 tag_cache text not null,
161 label_cache text not null,
163 score int not null default 0,
164 last_marked timestamp,
165 last_published timestamp,
167 unread boolean not null default true);
169 -- create index ttrss_user_entries_feed_id_index on ttrss_user_entries(feed_id);
170 create index ttrss_user_entries_owner_uid_index on ttrss_user_entries(owner_uid);
171 create index ttrss_user_entries_ref_id_index on ttrss_user_entries(ref_id);
172 create index ttrss_user_entries_feed_id on ttrss_user_entries(feed_id);
173 create index ttrss_user_entries_unread_idx on ttrss_user_entries(unread);
175 create table ttrss_entry_comments (id serial not null primary key,
176 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
177 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
178 private boolean not null default false,
179 date_entered timestamp not null);
181 create index ttrss_entry_comments_ref_id_index on ttrss_entry_comments(ref_id);
182 -- create index ttrss_entry_comments_owner_uid_index on ttrss_entry_comments(owner_uid);
184 create table ttrss_filter_types (id integer not null primary key,
185 name varchar(120) unique not null,
186 description varchar(250) not null unique);
188 insert into ttrss_filter_types (id,name,description) values (1, 'title', 'Title');
189 insert into ttrss_filter_types (id,name,description) values (2, 'content', 'Content');
190 insert into ttrss_filter_types (id,name,description) values (3, 'both',
192 insert into ttrss_filter_types (id,name,description) values (4, 'link',
194 insert into ttrss_filter_types (id,name,description) values (5, 'date',
196 insert into ttrss_filter_types (id,name,description) values (6, 'author', 'Author');
197 insert into ttrss_filter_types (id,name,description) values (7, 'tag', 'Article Tags');
199 create table ttrss_filter_actions (id integer not null primary key,
200 name varchar(120) unique not null,
201 description varchar(250) not null unique);
203 insert into ttrss_filter_actions (id,name,description) values (1, 'filter',
206 insert into ttrss_filter_actions (id,name,description) values (2, 'catchup',
209 insert into ttrss_filter_actions (id,name,description) values (3, 'mark',
212 insert into ttrss_filter_actions (id,name,description) values (4, 'tag',
215 insert into ttrss_filter_actions (id,name,description) values (5, 'publish',
218 insert into ttrss_filter_actions (id,name,description) values (6, 'score',
221 insert into ttrss_filter_actions (id,name,description) values (7, 'label',
224 insert into ttrss_filter_actions (id,name,description) values (8, 'stop',
225 'Stop / Do nothing');
227 create table ttrss_filters2(id serial not null primary key,
228 owner_uid integer not null references ttrss_users(id) on delete cascade,
229 match_any_rule boolean not null default false,
230 inverse boolean not null default false,
231 title varchar(250) not null default '',
232 order_id integer not null default 0,
233 enabled boolean not null default true);
235 create table ttrss_filters2_rules(id serial not null primary key,
236 filter_id integer not null references ttrss_filters2(id) on delete cascade,
237 reg_exp varchar(250) not null,
238 inverse boolean not null default false,
239 filter_type integer not null references ttrss_filter_types(id),
240 feed_id integer references ttrss_feeds(id) on delete cascade default null,
241 cat_id integer references ttrss_feed_categories(id) on delete cascade default null,
242 cat_filter boolean not null default false);
244 create table ttrss_filters2_actions(id serial not null primary key,
245 filter_id integer not null references ttrss_filters2(id) on delete cascade,
246 action_id integer not null default 1 references ttrss_filter_actions(id) on delete cascade,
247 action_param varchar(250) not null default '');
249 create table ttrss_tags (id serial not null primary key,
250 tag_name varchar(250) not null,
251 owner_uid integer not null references ttrss_users(id) on delete cascade,
252 post_int_id integer references ttrss_user_entries(int_id) ON DELETE CASCADE not null);
254 create index ttrss_tags_owner_uid_index on ttrss_tags(owner_uid);
255 create index ttrss_tags_post_int_id_idx on ttrss_tags(post_int_id);
257 create table ttrss_version (schema_version int not null);
259 insert into ttrss_version values (115);
261 create table ttrss_enclosures (id serial not null primary key,
262 content_url text not null,
263 content_type varchar(250) not null,
265 duration text not null,
266 post_id integer references ttrss_entries(id) ON DELETE cascade NOT NULL);
268 create index ttrss_enclosures_post_id_idx on ttrss_enclosures(post_id);
270 create table ttrss_settings_profiles(id serial not null primary key,
271 title varchar(250) not null,
272 owner_uid integer not null references ttrss_users(id) on delete cascade);
274 create table ttrss_prefs_types (id integer not null primary key,
275 type_name varchar(100) not null);
277 insert into ttrss_prefs_types (id, type_name) values (1, 'bool');
278 insert into ttrss_prefs_types (id, type_name) values (2, 'string');
279 insert into ttrss_prefs_types (id, type_name) values (3, 'integer');
281 create table ttrss_prefs_sections (id integer not null primary key,
282 order_id integer not null,
283 section_name varchar(100) not null);
285 insert into ttrss_prefs_sections (id, section_name, order_id) values (1, 'General', 0);
286 insert into ttrss_prefs_sections (id, section_name, order_id) values (2, 'Interface', 1);
287 insert into ttrss_prefs_sections (id, section_name, order_id) values (3, 'Advanced', 3);
288 insert into ttrss_prefs_sections (id, section_name, order_id) values (4, 'Digest', 2);
290 create table ttrss_prefs (pref_name varchar(250) not null primary key,
291 type_id integer not null references ttrss_prefs_types(id),
292 section_id integer not null default 1 references ttrss_prefs_sections(id),
293 access_level integer not null default 0,
294 def_value text not null);
296 create index ttrss_prefs_pref_name_idx on ttrss_prefs(pref_name);
298 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('PURGE_OLD_DAYS', 3, '60', 1);
299 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DEFAULT_UPDATE_INTERVAL', 3, '30', 1);
300 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DEFAULT_ARTICLE_LIMIT', 3, '30', 2);
301 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('ALLOW_DUPLICATE_POSTS', 1, 'true', 1);
302 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('ENABLE_FEED_CATS', 1, 'true', 2);
303 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('SHOW_CONTENT_PREVIEW', 1, 'true', 2);
304 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('SHORT_DATE_FORMAT', 2, 'M d, G:i', 3);
305 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('LONG_DATE_FORMAT', 2, 'D, M d Y - G:i', 3);
306 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('COMBINED_DISPLAY_MODE', 1, 'true', 2);
307 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('HIDE_READ_FEEDS', 1, 'false', 2);
308 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('ON_CATCHUP_SHOW_NEXT_FEED', 1, 'false', 2);
309 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('FEEDS_SORT_BY_UNREAD', 1, 'false', 2);
310 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('REVERSE_HEADLINES', 1, 'false', 2);
311 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DIGEST_ENABLE', 1, 'false', 4);
312 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('CONFIRM_FEED_CATCHUP', 1, 'true', 2);
313 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('CDM_AUTO_CATCHUP', 1, 'false', 2);
314 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_DEFAULT_VIEW_MODE', 2, 'adaptive', 1);
315 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_DEFAULT_VIEW_LIMIT', 3, '30', 1);
316 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_PREFS_ACTIVE_TAB', 2, '', 1);
317 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('STRIP_UNSAFE_TAGS', 1, 'true', 3);
318 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);
319 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('FRESH_ARTICLE_MAX_AGE', 3, '24', 2);
320 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DIGEST_CATCHUP', 1, 'false', 4);
321 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('CDM_EXPANDED', 1, 'true', 2);
322 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('PURGE_UNREAD_ARTICLES', 1, 'true', 3);
323 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('HIDE_READ_SHOWS_SPECIAL', 1, 'true', 2);
324 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('VFEED_GROUP_BY_FEED', 1, 'false', 2);
325 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('STRIP_IMAGES', 1, 'false', 2);
326 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_DEFAULT_VIEW_ORDER_BY', 2, 'default', 1);
327 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('ENABLE_API_ACCESS', 1, 'false', 1);
328 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_COLLAPSED_SPECIAL', 1, 'false', 1);
329 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_COLLAPSED_LABELS', 1, 'false', 1);
330 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_COLLAPSED_UNCAT', 1, 'false', 1);
331 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_COLLAPSED_FEEDLIST', 1, 'false', 1);
332 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_ENABLE_CATS', 1, 'false', 1);
333 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_SHOW_IMAGES', 1, 'false', 1);
334 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_HIDE_READ', 1, 'false', 1);
335 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_SORT_FEEDS_UNREAD', 1, 'false', 1);
336 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_THEME_ID', 2, '0', 1);
337 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('USER_TIMEZONE', 2, 'UTC', 1);
338 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('USER_STYLESHEET', 2, '', 2);
339 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('SORT_HEADLINES_BY_FEED_DATE', 1, 'false', 2);
340 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_BROWSE_CATS', 1, 'true', 1);
341 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('SSL_CERT_SERIAL', 2, '', 3);
342 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DIGEST_PREFERRED_TIME', 2, '00:00', 4);
343 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_PREFS_SHOW_EMPTY_CATS', 1, 'false', 1);
344 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_DEFAULT_INCLUDE_CHILDREN', 1, 'false', 1);
345 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('AUTO_ASSIGN_LABELS', 1, 'true', 3);
346 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_ENABLED_PLUGINS', 2, '', 1);
347 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_REVERSE_HEADLINES', 1, 'false', 1);
348 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('USER_CSS_THEME', 2, '', 2);
350 update ttrss_prefs set access_level = 1 where pref_name in ('ON_CATCHUP_SHOW_NEXT_FEED',
351 'SORT_HEADLINES_BY_FEED_DATE',
352 'VFEED_GROUP_BY_FEED',
353 'FRESH_ARTICLE_MAX_AGE',
355 'SHOW_CONTENT_PREVIEW',
356 'AUTO_ASSIGN_LABELS',
357 'HIDE_READ_SHOWS_SPECIAL');
359 create table ttrss_user_prefs (
360 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
361 pref_name varchar(250) not null references ttrss_prefs(pref_name) ON DELETE CASCADE,
362 profile integer references ttrss_settings_profiles(id) ON DELETE CASCADE,
363 value text not null);
365 create index ttrss_user_prefs_owner_uid_index on ttrss_user_prefs(owner_uid);
366 create index ttrss_user_prefs_pref_name_idx on ttrss_user_prefs(pref_name);
367 -- create index ttrss_user_prefs_value_index on ttrss_user_prefs(value);
369 create table ttrss_sessions (id varchar(250) unique not null primary key,
371 expire integer not null);
373 create index ttrss_sessions_expire_index on ttrss_sessions(expire);
375 create function SUBSTRING_FOR_DATE(timestamp, int, int) RETURNS text AS 'SELECT SUBSTRING(CAST($1 AS text), $2, $3)' LANGUAGE 'sql';
377 create table ttrss_feedbrowser_cache (
378 feed_url text not null primary key,
380 site_url text not null,
381 subscribers integer not null);
383 create table ttrss_labels2 (id serial not null primary key,
384 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
385 fg_color varchar(15) not null default '',
386 bg_color varchar(15) not null default '',
387 caption varchar(250) not null
390 create table ttrss_user_labels2 (
391 label_id integer not null references ttrss_labels2(id) ON DELETE CASCADE,
392 article_id integer not null references ttrss_entries(id) ON DELETE CASCADE
395 create table ttrss_access_keys (id serial not null primary key,
396 access_key varchar(250) not null,
397 feed_id varchar(250) not null,
398 is_cat boolean not null default false,
399 owner_uid integer not null references ttrss_users(id) on delete cascade);
401 create table ttrss_linked_instances (id serial not null primary key,
402 last_connected timestamp not null,
403 last_status_in integer not null,
404 last_status_out integer not null,
405 access_key varchar(250) not null unique,
406 access_url text not null);
408 create table ttrss_linked_feeds (
409 feed_url text not null,
410 site_url text not null,
412 created timestamp not null,
413 updated timestamp not null,
414 instance_id integer not null references ttrss_linked_instances(id) ON DELETE CASCADE,
415 subscribers integer not null);
417 create table ttrss_plugin_storage (
418 id serial not null primary key,
419 name varchar(100) not null,
420 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
421 content text not null);