]> git.wh0rd.org - tt-rss.git/blob - schema/ttrss_schema_pgsql.sql
d5d3f88f002a923ca143efeeddaa72eb43be123d
[tt-rss.git] / schema / ttrss_schema_pgsql.sql
1 drop table if exists ttrss_linked_feeds;
2 drop table if exists ttrss_linked_instances;
3 drop table if exists ttrss_access_keys;
4 drop table if exists ttrss_user_labels2;
5 drop table if exists ttrss_labels2;
6 drop table if exists ttrss_feedbrowser_cache;
7 drop table if exists ttrss_version;
8 drop table if exists ttrss_labels;
9 drop table if exists ttrss_filters;
10 drop table if exists ttrss_filter_types;
11 drop table if exists ttrss_filter_actions;
12 drop table if exists ttrss_user_prefs;
13 drop table if exists ttrss_prefs;
14 drop table if exists ttrss_prefs_types;
15 drop table if exists ttrss_prefs_sections;
16 drop table if exists ttrss_tags;
17 drop table if exists ttrss_enclosures;
18 drop table if exists ttrss_settings_profiles;
19 drop table if exists ttrss_entry_comments;
20 drop table if exists ttrss_user_entries;
21 drop table if exists ttrss_entries;
22 drop table if exists ttrss_scheduled_updates;
23 drop table if exists ttrss_counters_cache;
24 drop table if exists ttrss_cat_counters_cache;
25 drop table if exists ttrss_archived_feeds;
26 drop table if exists ttrss_feeds;
27 drop table if exists ttrss_feed_categories;
28 drop table if exists ttrss_users;
29 drop table if exists ttrss_themes;
30 drop table if exists ttrss_sessions;
31 drop function if exists SUBSTRING_FOR_DATE(timestamp, int, int);
32
33 begin;
34
35 create table ttrss_users (id serial not null primary key,
36 login varchar(120) not null unique,
37 pwd_hash varchar(250) not null,
38 last_login timestamp default null,
39 access_level integer not null default 0,
40 email varchar(250) not null default '',
41 full_name varchar(250) not null default '',
42 email_digest boolean not null default false,
43 last_digest_sent timestamp default null,
44 salt varchar(250) not null default '',
45 twitter_oauth text default null,
46 created timestamp default null);
47
48 insert into ttrss_users (login,pwd_hash,access_level) values ('admin',
49 'SHA1:5baa61e4c9b93f3f0682250b6cf8331b7ee68fd8', 10);
50
51 create table ttrss_feed_categories(id serial not null primary key,
52 owner_uid integer not null references ttrss_users(id) on delete cascade,
53 collapsed boolean not null default false,
54 order_id integer not null default 0,
55 parent_cat integer references ttrss_feed_categories(id) on delete set null,
56 title varchar(200) not null);
57
58 create table ttrss_feeds (id serial not null primary key,
59 owner_uid integer not null references ttrss_users(id) on delete cascade,
60 title varchar(200) not null,
61 cat_id integer default null references ttrss_feed_categories(id) on delete set null,
62 feed_url text not null,
63 icon_url varchar(250) not null default '',
64 update_interval integer not null default 0,
65 purge_interval integer not null default 0,
66 last_updated timestamp default null,
67 last_error text not null default '',
68 site_url varchar(250) not null default '',
69 auth_login varchar(250) not null default '',
70 parent_feed integer default null references ttrss_feeds(id) on delete set null,
71 private boolean not null default false,
72 auth_pass varchar(250) not null default '',
73 hidden boolean not null default false,
74 include_in_digest boolean not null default true,
75 rtl_content boolean not null default false,
76 cache_images boolean not null default false,
77 last_viewed timestamp default null,
78 last_update_started timestamp default null,
79 update_method integer not null default 0,
80 always_display_enclosures boolean not null default false,
81 order_id integer not null default 0,
82 mark_unread_on_update boolean not null default false,
83 update_on_checksum_change boolean not null default false,
84 strip_images boolean not null default false,
85 pubsub_state integer not null default 0,
86 favicon_last_checked timestamp default null,
87 auth_pass_encrypted boolean not null default false);
88
89 create index ttrss_feeds_owner_uid_index on ttrss_feeds(owner_uid);
90 create index ttrss_feeds_cat_id_idx on ttrss_feeds(cat_id);
91
92 insert into ttrss_feeds (owner_uid, title, feed_url) values
93 (1, 'Tiny Tiny RSS: New Releases', 'http://tt-rss.org/releases.rss');
94
95 insert into ttrss_feeds (owner_uid, title, feed_url) values
96 (1, 'Tiny Tiny RSS: Forum', 'http://tt-rss.org/forum/rss.php');
97
98 create table ttrss_archived_feeds (id integer not null primary key,
99 owner_uid integer not null references ttrss_users(id) on delete cascade,
100 title varchar(200) not null,
101 feed_url text not null,
102 site_url varchar(250) not null default '');
103
104 create table ttrss_counters_cache (
105 feed_id integer not null,
106 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
107 updated timestamp not null,
108 value integer not null default 0);
109
110 create index ttrss_counters_cache_feed_id_idx on ttrss_counters_cache(feed_id);
111 create index ttrss_counters_cache_owner_uid_idx on ttrss_counters_cache(owner_uid);
112 create index ttrss_counters_cache_value_idx on ttrss_counters_cache(value);
113
114 create table ttrss_cat_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_cat_counters_cache_owner_uid_idx on ttrss_cat_counters_cache(owner_uid);
121
122 create table ttrss_entries (id serial not null primary key,
123 title text not null,
124 guid text not null unique,
125 link text not null,
126 updated timestamp not null,
127 content text not null,
128 content_hash varchar(250) not null,
129 no_orig_date boolean not null default false,
130 date_entered timestamp not null,
131 date_updated timestamp not null,
132 num_comments integer not null default 0,
133 comments varchar(250) not null default '',
134 author varchar(250) not null default '');
135
136 create index ttrss_entries_guid_index on ttrss_entries(guid);
137 -- create index ttrss_entries_title_index on ttrss_entries(title);
138 create index ttrss_entries_date_entered_index on ttrss_entries(date_entered);
139 create index ttrss_entries_updated_idx on ttrss_entries(updated);
140
141 create table ttrss_user_entries (
142 int_id serial not null primary key,
143 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
144 uuid varchar(200) not null,
145 feed_id int references ttrss_feeds(id) ON DELETE CASCADE,
146 orig_feed_id integer references ttrss_archived_feeds(id) ON DELETE SET NULL,
147 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
148 marked boolean not null default false,
149 published boolean not null default false,
150 tag_cache text not null,
151 label_cache text not null,
152 last_read timestamp,
153 score int not null default 0,
154 note text,
155 unread boolean not null default true);
156
157 -- create index ttrss_user_entries_feed_id_index on ttrss_user_entries(feed_id);
158 create index ttrss_user_entries_owner_uid_index on ttrss_user_entries(owner_uid);
159 create index ttrss_user_entries_ref_id_index on ttrss_user_entries(ref_id);
160 create index ttrss_user_entries_feed_id on ttrss_user_entries(feed_id);
161 create index ttrss_user_entries_unread_idx on ttrss_user_entries(unread);
162
163 create table ttrss_entry_comments (id serial not null primary key,
164 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
165 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
166 private boolean not null default false,
167 date_entered timestamp not null);
168
169 create index ttrss_entry_comments_ref_id_index on ttrss_entry_comments(ref_id);
170 -- create index ttrss_entry_comments_owner_uid_index on ttrss_entry_comments(owner_uid);
171
172 create table ttrss_filter_types (id integer not null primary key,
173 name varchar(120) unique not null,
174 description varchar(250) not null unique);
175
176 insert into ttrss_filter_types (id,name,description) values (1, 'title', 'Title');
177 insert into ttrss_filter_types (id,name,description) values (2, 'content', 'Content');
178 insert into ttrss_filter_types (id,name,description) values (3, 'both',
179 'Title or Content');
180 insert into ttrss_filter_types (id,name,description) values (4, 'link',
181 'Link');
182 insert into ttrss_filter_types (id,name,description) values (5, 'date',
183 'Article Date');
184 insert into ttrss_filter_types (id,name,description) values (6, 'author', 'Author');
185 insert into ttrss_filter_types (id,name,description) values (7, 'tag', 'Article Tags');
186
187 create table ttrss_filter_actions (id integer not null primary key,
188 name varchar(120) unique not null,
189 description varchar(250) not null unique);
190
191 insert into ttrss_filter_actions (id,name,description) values (1, 'filter',
192 'Delete article');
193
194 insert into ttrss_filter_actions (id,name,description) values (2, 'catchup',
195 'Mark as read');
196
197 insert into ttrss_filter_actions (id,name,description) values (3, 'mark',
198 'Set starred');
199
200 insert into ttrss_filter_actions (id,name,description) values (4, 'tag',
201 'Assign tags');
202
203 insert into ttrss_filter_actions (id,name,description) values (5, 'publish',
204 'Publish article');
205
206 insert into ttrss_filter_actions (id,name,description) values (6, 'score',
207 'Modify score');
208
209 insert into ttrss_filter_actions (id,name,description) values (7, 'label',
210 'Assign label');
211
212 create table ttrss_filters (id serial not null primary key,
213 owner_uid integer not null references ttrss_users(id) on delete cascade,
214 feed_id integer references ttrss_feeds(id) on delete cascade default null,
215 filter_type integer not null references ttrss_filter_types(id),
216 reg_exp varchar(250) not null,
217 filter_param varchar(250) not null default '',
218 enabled boolean not null default true,
219 inverse boolean not null default false,
220 cat_filter boolean not null default false,
221 cat_id integer references ttrss_feed_categories(id) on delete cascade default null,
222 action_id integer not null default 1 references ttrss_filter_actions(id) on delete cascade,
223 action_param varchar(250) not null default '');
224
225 create table ttrss_tags (id serial not null primary key,
226 tag_name varchar(250) not null,
227 owner_uid integer not null references ttrss_users(id) on delete cascade,
228 post_int_id integer references ttrss_user_entries(int_id) ON DELETE CASCADE not null);
229
230 create index ttrss_tags_owner_uid_index on ttrss_tags(owner_uid);
231 create index ttrss_tags_post_int_id_idx on ttrss_tags(post_int_id);
232
233 create table ttrss_version (schema_version int not null);
234
235 insert into ttrss_version values (93);
236
237 create table ttrss_enclosures (id serial not null primary key,
238 content_url text not null,
239 content_type varchar(250) not null,
240 title text not null,
241 duration text not null,
242 post_id integer references ttrss_entries(id) ON DELETE cascade NOT NULL);
243
244 create index ttrss_enclosures_post_id_idx on ttrss_enclosures(post_id);
245
246 create table ttrss_settings_profiles(id serial not null primary key,
247 title varchar(250) not null,
248 owner_uid integer not null references ttrss_users(id) on delete cascade);
249
250 create table ttrss_prefs_types (id integer not null primary key,
251 type_name varchar(100) not null);
252
253 insert into ttrss_prefs_types (id, type_name) values (1, 'bool');
254 insert into ttrss_prefs_types (id, type_name) values (2, 'string');
255 insert into ttrss_prefs_types (id, type_name) values (3, 'integer');
256
257 create table ttrss_prefs_sections (id integer not null primary key,
258 section_name varchar(100) not null);
259
260 insert into ttrss_prefs_sections (id, section_name) values (1, 'General');
261 insert into ttrss_prefs_sections (id, section_name) values (2, 'Interface');
262 insert into ttrss_prefs_sections (id, section_name) values (3, 'Advanced');
263
264 create table ttrss_prefs (pref_name varchar(250) not null primary key,
265 type_id integer not null references ttrss_prefs_types(id),
266 section_id integer not null references ttrss_prefs_sections(id) default 1,
267 short_desc text not null,
268 help_text text not null default '',
269 access_level integer not null default 0,
270 def_value text not null);
271
272 create index ttrss_prefs_pref_name_idx on ttrss_prefs(pref_name);
273
274 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('PURGE_OLD_DAYS', 3, '60', 'Purge old posts after this number of days (0 - disables)',1);
275
276 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('DEFAULT_UPDATE_INTERVAL', 3, '30', 'Default interval between feed updates',1);
277
278 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('DEFAULT_ARTICLE_LIMIT', 3, '30', 'Amount of articles to display at once',2);
279
280 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('ALLOW_DUPLICATE_POSTS', 1, 'true', 'Allow duplicate posts',1, 'This option is useful when you are reading several planet-type aggregators with partially colliding userbase. When disabled, it forces same posts from different feeds to appear only once.');
281
282 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('ENABLE_FEED_CATS', 1, 'true', 'Enable feed categories',2);
283
284 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('SHOW_CONTENT_PREVIEW', 1, 'true', 'Show content preview in headlines list',2);
285
286 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('SHORT_DATE_FORMAT', 2, 'M d, G:i', 'Short date format',3);
287
288 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('LONG_DATE_FORMAT', 2, 'D, M d Y - G:i', 'Long date format',3);
289
290 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('COMBINED_DISPLAY_MODE', 1, 'false', 'Combined feed display',2, 'Display expanded list of feed articles, instead of separate displays for headlines and article content');
291
292 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('HIDE_READ_FEEDS', 1, 'false', 'Hide feeds with no unread messages',2);
293
294 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('ON_CATCHUP_SHOW_NEXT_FEED', 1, 'false', 'On catchup show next feed',2, 'Automatically open next feed with unread articles after marking one as read');
295
296 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('FEEDS_SORT_BY_UNREAD', 1, 'false', 'Sort feeds by unread articles count',2);
297
298 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('REVERSE_HEADLINES', 1, 'false', 'Reverse headline order (oldest first)',2);
299
300 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('DIGEST_ENABLE', 1, 'false', 'Enable e-mail digest',1, 'This option enables sending daily digest of new (and unread) headlines on your configured e-mail address');
301
302 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('CONFIRM_FEED_CATCHUP', 1, 'true', 'Confirm marking feed as read',3);
303
304 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('CDM_AUTO_CATCHUP', 1, 'false', 'Automatically mark articles as read',3, 'This option enables marking articles as read automatically while you scroll article list.');
305
306 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_DEFAULT_VIEW_MODE', 2, 'adaptive', '', 1);
307
308 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_DEFAULT_VIEW_LIMIT', 3, '30', '', 1);
309
310 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_PREFS_ACTIVE_TAB', 2, '', '', 1);
311
312 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('STRIP_UNSAFE_TAGS', 1, 'true', 'Strip unsafe tags from articles', 3, 'Strip all but most common HTML tags when reading articles.');
313
314 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('BLACKLISTED_TAGS', 2, 'main, generic, misc, uncategorized, blog, blogroll, general, news', 'Blacklisted tags', 3, 'When auto-detecting tags in articles these tags will not be applied (comma-separated list).');
315
316 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('FRESH_ARTICLE_MAX_AGE', 3, '24', 'Maximum age of fresh articles (in hours)',2);
317
318 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('DIGEST_CATCHUP', 1, 'false', 'Mark articles in e-mail digest as read',1);
319
320 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('CDM_EXPANDED', 1, 'true', 'Automatically expand articles in combined mode',3);
321
322 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('PURGE_UNREAD_ARTICLES', 1, 'true', 'Purge unread articles',3);
323
324 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('HIDE_READ_SHOWS_SPECIAL', 1, 'true', 'Show special feeds when hiding read feeds',3);
325
326 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('VFEED_GROUP_BY_FEED', 1, 'false', 'Group headlines in virtual feeds',2, 'When this option is enabled, headlines in Special feeds and Labels are grouped by feeds');
327
328 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('STRIP_IMAGES', 1, 'false', 'Do not show images in articles', 2);
329
330 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_DEFAULT_VIEW_ORDER_BY', 2, 'default', '', 1);
331
332 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('ENABLE_API_ACCESS', 1, 'false', 'Enable external API', 3);
333
334 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_COLLAPSED_SPECIAL', 1, 'false', '', 1);
335
336 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_COLLAPSED_LABELS', 1, 'false', '', 1);
337
338 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_COLLAPSED_UNCAT', 1, 'false', '', 1);
339
340 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_COLLAPSED_FEEDLIST', 1, 'false', '', 1);
341
342 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_MOBILE_ENABLE_CATS', 1, 'false', '', 1);
343
344 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_MOBILE_SHOW_IMAGES', 1, 'false', '', 1);
345
346 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_MOBILE_HIDE_READ', 1, 'false', '', 1);
347
348 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_MOBILE_SORT_FEEDS_UNREAD', 1, 'false', '', 1);
349
350 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_THEME_ID', 2, '0', '', 1);
351
352 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('USER_TIMEZONE', 2, 'UTC', 'User timezone', 1);
353
354 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('SORT_HEADLINES_BY_FEED_DATE', 1, 'true', 'Sort headlines by feed date',3, 'Use feed-specified date to sort headlines instead of local import date.');
355
356 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('USER_STYLESHEET', 2, '', 'Customize stylesheet', 2, 'Customize CSS stylesheet to your liking');
357
358 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_MOBILE_BROWSE_CATS', 1, 'true', '', 1);
359
360 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('SSL_CERT_SERIAL', 2, '', 'Login with an SSL certificate',3, 'Click to register your SSL client certificate with tt-rss');
361
362 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('DIGEST_PREFERRED_TIME', 2, '00:00', 'Try to send digests around specified time', 1, 'Uses UTC timezone');
363
364 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_PREFS_SHOW_EMPTY_CATS', 1, 'false', '', 1);
365
366 create table ttrss_user_prefs (
367 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
368 pref_name varchar(250) not null references ttrss_prefs(pref_name) ON DELETE CASCADE,
369 profile integer references ttrss_settings_profiles(id) ON DELETE CASCADE,
370 value text not null);
371
372 create index ttrss_user_prefs_owner_uid_index on ttrss_user_prefs(owner_uid);
373 create index ttrss_user_prefs_pref_name_idx on ttrss_user_prefs(pref_name);
374 -- create index ttrss_user_prefs_value_index on ttrss_user_prefs(value);
375
376 create table ttrss_sessions (id varchar(250) unique not null primary key,
377 data text,
378 expire integer not null);
379
380 create index ttrss_sessions_expire_index on ttrss_sessions(expire);
381
382 create function SUBSTRING_FOR_DATE(timestamp, int, int) RETURNS text AS 'SELECT SUBSTRING(CAST($1 AS text), $2, $3)' LANGUAGE 'sql';
383
384 create table ttrss_feedbrowser_cache (
385 feed_url text not null primary key,
386 title text not null,
387 site_url text not null,
388 subscribers integer not null);
389
390 create table ttrss_labels2 (id serial not null primary key,
391 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
392 fg_color varchar(15) not null default '',
393 bg_color varchar(15) not null default '',
394 caption varchar(250) not null
395 );
396
397 create table ttrss_user_labels2 (
398 label_id integer not null references ttrss_labels2(id) ON DELETE CASCADE,
399 article_id integer not null references ttrss_entries(id) ON DELETE CASCADE
400 );
401
402 create table ttrss_access_keys (id serial not null primary key,
403 access_key varchar(250) not null,
404 feed_id varchar(250) not null,
405 is_cat boolean not null default false,
406 owner_uid integer not null references ttrss_users(id) on delete cascade);
407
408 create table ttrss_linked_instances (id serial not null primary key,
409 last_connected timestamp not null,
410 last_status_in integer not null,
411 last_status_out integer not null,
412 access_key varchar(250) not null unique,
413 access_url text not null);
414
415 create table ttrss_linked_feeds (
416 feed_url text not null,
417 site_url text not null,
418 title text not null,
419 created timestamp not null,
420 updated timestamp not null,
421 instance_id integer not null references ttrss_linked_instances(id) ON DELETE CASCADE,
422 subscribers integer not null);
423
424 commit;