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