]> git.wh0rd.org - tt-rss.git/blob - schema/ttrss_schema_pgsql.sql
replace old-style published feed with universal secretkey-based approach used for...
[tt-rss.git] / schema / ttrss_schema_pgsql.sql
1 drop table ttrss_access_keys;
2 drop table ttrss_user_labels2;
3 drop table ttrss_labels2;
4 drop table ttrss_feedbrowser_cache;
5 drop table ttrss_version;
6 drop table ttrss_labels;
7 drop table ttrss_filters;
8 drop table ttrss_filter_types;
9 drop table ttrss_filter_actions;
10 drop table ttrss_user_prefs;
11 drop table ttrss_prefs;
12 drop table ttrss_prefs_types;
13 drop table ttrss_prefs_sections;
14 drop table ttrss_tags;
15 drop table ttrss_enclosures;
16 drop table ttrss_settings_profiles;
17 drop table ttrss_entry_comments;
18 drop table ttrss_user_entries;
19 drop table ttrss_entries;
20 drop table ttrss_scheduled_updates;
21 drop table ttrss_counters_cache;
22 drop table ttrss_cat_counters_cache;
23 drop table ttrss_archived_feeds;
24 drop table ttrss_feeds;
25 drop table ttrss_feed_categories;
26 drop table ttrss_users;
27 drop table ttrss_themes;
28 drop table ttrss_sessions;
29 drop function SUBSTRING_FOR_DATE(timestamp, int, int);
30
31 begin;
32
33 create table ttrss_themes(id serial not null primary key,
34 theme_name varchar(200) not null,
35 theme_path varchar(200) not null);
36
37 insert into ttrss_themes (theme_name, theme_path) values ('Old-skool', 'compat');
38 insert into ttrss_themes (theme_name, theme_path) values ('Graycube', 'graycube');
39 insert into ttrss_themes (theme_name, theme_path) values ('Default (Compact)', 'compact');
40 insert into ttrss_themes (theme_name, theme_path) values ('Three-pane', '3pane');
41
42 create table ttrss_users (id serial not null primary key,
43 login varchar(120) not null unique,
44 pwd_hash varchar(250) not null,
45 last_login timestamp default null,
46 access_level integer not null default 0,
47 email varchar(250) not null default '',
48 email_digest boolean not null default false,
49 last_digest_sent timestamp default null,
50 created timestamp default null,
51 theme_id integer references ttrss_themes(id) 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 title varchar(200) not null);
61
62 create table ttrss_feeds (id serial not null primary key,
63 owner_uid integer not null references ttrss_users(id) on delete cascade,
64 title varchar(200) not null,
65 cat_id integer default null references ttrss_feed_categories(id) on delete set null,
66 feed_url text not null,
67 icon_url varchar(250) not null default '',
68 update_interval integer not null default 0,
69 purge_interval integer not null default 0,
70 last_updated timestamp default null,
71 last_error text not null default '',
72 site_url varchar(250) not null default '',
73 auth_login varchar(250) not null default '',
74 parent_feed integer default null references ttrss_feeds(id) on delete set null,
75 private boolean not null default false,
76 auth_pass varchar(250) not null default '',
77 hidden boolean not null default false,
78 include_in_digest boolean not null default true,
79 rtl_content boolean not null default false,
80 cache_images boolean not null default false,
81 last_viewed timestamp default null,
82 last_update_started timestamp default null,
83 update_method integer not null default 0,
84 always_display_enclosures boolean not null default false,
85 auth_pass_encrypted boolean not null default false);
86
87 create index ttrss_feeds_owner_uid_index on ttrss_feeds(owner_uid);
88
89 insert into ttrss_feeds (owner_uid, title, feed_url) values
90 (1, 'Tiny Tiny RSS: New Releases', 'http://tt-rss.org/releases.rss');
91
92 insert into ttrss_feeds (owner_uid, title, feed_url) values
93 (1, 'Tiny Tiny RSS: Forum', 'http://tt-rss.org/forum/rss.php');
94
95 create table ttrss_archived_feeds (id integer not null primary key,
96 owner_uid integer not null references ttrss_users(id) on delete cascade,
97 title varchar(200) not null,
98 feed_url text not null,
99 site_url varchar(250) not null default '');
100
101 create table ttrss_counters_cache (
102 feed_id integer not null,
103 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
104 updated timestamp not null,
105 value integer not null default 0);
106
107 create table ttrss_cat_counters_cache (
108 feed_id integer not null,
109 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
110 updated timestamp not null,
111 value integer not null default 0);
112
113 create table ttrss_entries (id serial not null primary key,
114 title text not null,
115 guid text not null unique,
116 link text not null,
117 updated timestamp not null,
118 content text not null,
119 content_hash varchar(250) not null,
120 no_orig_date boolean not null default false,
121 date_entered timestamp not null,
122 date_updated timestamp not null,
123 num_comments integer not null default 0,
124 comments varchar(250) not null default '',
125 author varchar(250) not null default '');
126
127 create index ttrss_entries_guid_index on ttrss_entries(guid);
128 -- create index ttrss_entries_title_index on ttrss_entries(title);
129 create index ttrss_entries_date_entered_index on ttrss_entries(date_entered);
130
131 create table ttrss_user_entries (
132 int_id serial not null primary key,
133 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
134 feed_id int references ttrss_feeds(id) ON DELETE CASCADE,
135 orig_feed_id integer references ttrss_archived_feeds(id) ON DELETE SET NULL,
136 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
137 marked boolean not null default false,
138 published boolean not null default false,
139 last_read timestamp,
140 score int not null default 0,
141 note text,
142 unread boolean not null default true);
143
144 -- create index ttrss_user_entries_feed_id_index on ttrss_user_entries(feed_id);
145 -- create index ttrss_user_entries_owner_uid_index on ttrss_user_entries(owner_uid);
146 create index ttrss_user_entries_ref_id_index on ttrss_user_entries(ref_id);
147 create index ttrss_user_entries_feed_id on ttrss_user_entries(feed_id);
148
149 create table ttrss_entry_comments (id serial not null primary key,
150 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
151 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
152 private boolean not null default false,
153 date_entered timestamp not null);
154
155 create index ttrss_entry_comments_ref_id_index on ttrss_entry_comments(ref_id);
156 -- create index ttrss_entry_comments_owner_uid_index on ttrss_entry_comments(owner_uid);
157
158 create table ttrss_filter_types (id integer not null primary key,
159 name varchar(120) unique not null,
160 description varchar(250) not null unique);
161
162 insert into ttrss_filter_types (id,name,description) values (1, 'title', 'Title');
163 insert into ttrss_filter_types (id,name,description) values (2, 'content', 'Content');
164 insert into ttrss_filter_types (id,name,description) values (3, 'both',
165 'Title or Content');
166 insert into ttrss_filter_types (id,name,description) values (4, 'link',
167 'Link');
168 insert into ttrss_filter_types (id,name,description) values (5, 'date',
169 'Article Date');
170 insert into ttrss_filter_types (id,name,description) values (6, 'author', 'Author');
171
172 create table ttrss_filter_actions (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_actions (id,name,description) values (1, 'filter',
177 'Filter article');
178
179 insert into ttrss_filter_actions (id,name,description) values (2, 'catchup',
180 'Mark as read');
181
182 insert into ttrss_filter_actions (id,name,description) values (3, 'mark',
183 'Set starred');
184
185 insert into ttrss_filter_actions (id,name,description) values (4, 'tag',
186 'Assign tags');
187
188 insert into ttrss_filter_actions (id,name,description) values (5, 'publish',
189 'Publish article');
190
191 insert into ttrss_filter_actions (id,name,description) values (6, 'score',
192 'Modify score');
193
194 insert into ttrss_filter_actions (id,name,description) values (7, 'label',
195 'Assign label');
196
197 create table ttrss_filters (id serial not null primary key,
198 owner_uid integer not null references ttrss_users(id) on delete cascade,
199 feed_id integer references ttrss_feeds(id) on delete cascade default null,
200 filter_type integer not null references ttrss_filter_types(id),
201 reg_exp varchar(250) not null,
202 filter_param varchar(250) not null default '',
203 enabled boolean not null default true,
204 inverse boolean not null default false,
205 action_id integer not null default 1 references ttrss_filter_actions(id) on delete cascade,
206 action_param varchar(250) not null default '');
207
208 create table ttrss_tags (id serial not null primary key,
209 tag_name varchar(250) not null,
210 owner_uid integer not null references ttrss_users(id) on delete cascade,
211 post_int_id integer references ttrss_user_entries(int_id) ON DELETE CASCADE not null);
212
213 create index ttrss_tags_owner_uid_index on ttrss_tags(owner_uid);
214
215 create table ttrss_version (schema_version int not null);
216
217 insert into ttrss_version values (69);
218
219 create table ttrss_enclosures (id serial not null primary key,
220 content_url text not null,
221 content_type varchar(250) not null,
222 title text not null,
223 duration text not null,
224 post_id integer references ttrss_entries(id) ON DELETE cascade NOT NULL);
225
226 create table ttrss_settings_profiles(id serial not null primary key,
227 title varchar(250) not null,
228 owner_uid integer not null references ttrss_users(id) on delete cascade);
229
230 create table ttrss_prefs_types (id integer not null primary key,
231 type_name varchar(100) not null);
232
233 insert into ttrss_prefs_types (id, type_name) values (1, 'bool');
234 insert into ttrss_prefs_types (id, type_name) values (2, 'string');
235 insert into ttrss_prefs_types (id, type_name) values (3, 'integer');
236
237 create table ttrss_prefs_sections (id integer not null primary key,
238 section_name varchar(100) not null);
239
240 insert into ttrss_prefs_sections (id, section_name) values (1, 'General');
241 insert into ttrss_prefs_sections (id, section_name) values (2, 'Interface');
242 insert into ttrss_prefs_sections (id, section_name) values (3, 'Advanced');
243
244 create table ttrss_prefs (pref_name varchar(250) not null primary key,
245 type_id integer not null references ttrss_prefs_types(id),
246 section_id integer not null references ttrss_prefs_sections(id) default 1,
247 short_desc text not null,
248 help_text text not null default '',
249 access_level integer not null default 0,
250 def_value text not null);
251
252 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('ENABLE_FEED_ICONS', 1, 'true', 'Enable feed icons',3);
253 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);
254 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('UPDATE_POST_ON_CHECKSUM_CHANGE', 1, 'true', 'Update post on checksum change',1);
255 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('ENABLE_LABELS', 1, 'false', 'Enable labels',3,
256 'Experimental support for virtual feeds based on user crafted SQL queries. This feature is highly experimental and at this point not user friendly. Use with caution.');
257
258 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);
259
260 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);
261
262 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,
263 '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.');
264
265 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('USER_STYLESHEET_URL', 2, '', 'User stylesheet URL',2,
266 'Link to user stylesheet to override default style, disabled if empty.');
267
268 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('ENABLE_FEED_CATS', 1, 'false', 'Enable feed categories',2);
269
270 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);
271
272 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);
273 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);
274
275 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('HEADLINES_SMART_DATE', 1, 'true', 'Use more accessible date/time format for headlines',3);
276
277 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,
278 'Display expanded list of feed articles, instead of separate displays for headlines and article content');
279
280 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);
281
282 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('OPEN_LINKS_IN_NEW_WINDOW', 1, 'true', 'Open article links in new browser window',2);
283
284 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,
285 'When "Mark as read" button is clicked in toolbar, automatically open next feed with unread articles.');
286
287 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);
288
289 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('EXTENDED_FEEDLIST', 1, 'false', 'Show additional information in feedlist',3);
290
291 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('MARK_UNREAD_ON_UPDATE', 1, 'false', 'Set articles as unread on update',3);
292
293 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);
294
295 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,
296 'This option enables sending daily digest of new (and unread) headlines on your configured e-mail address');
297
298 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);
299
300 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('CDM_AUTO_CATCHUP', 1, 'false', 'Mark articles as read automatically',2,
301 'This option enables marking articles as read automatically in combined mode (except for Fresh articles feed) while you scroll article list.');
302
303 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_DEFAULT_VIEW_MODE', 2, 'adaptive', '', 1);
304
305 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_DEFAULT_VIEW_LIMIT', 3, '30', '', 1);
306
307 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_PREFS_ACTIVE_TAB', 2, '', '', 1);
308
309 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_INFOBOX_DISABLE_OVERLAY', 1, 'false', '', 1);
310
311 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,
312 '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,
315 'When auto-detecting tags in articles these tags will not be applied (comma-separated list).');
316
317 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('ENABLE_SEARCH_TOOLBAR', 1, 'false', 'Enable search toolbar',2);
318
319 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_PREFS_ENABLE_PAGINATION', 2, '', '', 1);
320
321 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_PREFS_PUBLISH_KEY', 2, '', '', 1);
322
323 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);
324
325 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);
326
327 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);
328
329 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('PURGE_UNREAD_ARTICLES', 1, 'true', 'Purge unread articles',3);
330
331 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);
332
333 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('HIDE_FEEDLIST', 1, 'false', 'Hide feedlist',2, 'This option hides feedlist and allows it to be toggled on the fly, useful for small screens.');
334
335 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,
336 'When this option is enabled, headlines in Special feeds and Labels are grouped by feeds');
337
338 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('SYNC_COUNTERS', 1, 'false', 'Prefer more accurate feedlist counters to UI speed',3);
339
340 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);
341
342 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('ENABLE_FLASH_PLAYER', 1, 'true', 'Enable inline MP3 player', 3, 'Enable the Flash-based XSPF Player to play MP3-format podcast enclosures.');
343
344 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_DEFAULT_VIEW_ORDER_BY', 2, 'default', '', 1);
345
346 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('ENABLE_OFFLINE_READING', 1, 'false', 'Enable offline reading',1, 'Synchronize new articles for offline reading using Google Gears.');
347
348 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('ENABLE_API_ACCESS', 1, 'false', 'Enable external API', 3);
349
350 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_COLLAPSED_SPECIAL', 1, 'false', '', 1);
351
352 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_COLLAPSED_LABELS', 1, 'false', '', 1);
353
354 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_COLLAPSED_UNCAT', 1, 'false', '', 1);
355
356 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_COLLAPSED_FEEDLIST', 1, 'false', '', 1);
357
358 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_MOBILE_ENABLE_CATS', 1, 'false', '', 1);
359
360 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_MOBILE_SHOW_IMAGES', 1, 'false', '', 1);
361
362 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_MOBILE_HIDE_READ', 1, 'false', '', 1);
363
364 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_MOBILE_SORT_FEEDS_UNREAD', 1, 'false', '', 1);
365
366 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_THEME_ID', 2, '0', '', 1);
367
368 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('USER_TIMEZONE', 2, 'UTC', 'User timezone', 1);
369
370 create table ttrss_user_prefs (
371 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
372 pref_name varchar(250) not null references ttrss_prefs(pref_name) ON DELETE CASCADE,
373 profile integer references ttrss_settings_profiles(id) ON DELETE CASCADE,
374 value text not null);
375
376 create index ttrss_user_prefs_owner_uid_index on ttrss_user_prefs(owner_uid);
377 -- create index ttrss_user_prefs_value_index on ttrss_user_prefs(value);
378
379 create table ttrss_scheduled_updates (id serial not null primary key,
380 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
381 feed_id integer default null references ttrss_feeds(id) ON DELETE CASCADE,
382 entered timestamp not null default NOW());
383
384 create table ttrss_sessions (id varchar(250) unique not null primary key,
385 data text,
386 expire integer not null);
387
388 create index ttrss_sessions_expire_index on ttrss_sessions(expire);
389
390 create function SUBSTRING_FOR_DATE(timestamp, int, int) RETURNS text AS 'SELECT SUBSTRING(CAST($1 AS text), $2, $3)' LANGUAGE 'sql';
391
392 create table ttrss_feedbrowser_cache (
393 feed_url text not null primary key,
394 title text not null,
395 subscribers integer not null);
396
397 create table ttrss_labels2 (id serial not null primary key,
398 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
399 fg_color varchar(15) not null default '',
400 bg_color varchar(15) not null default '',
401 caption varchar(250) not null
402 );
403
404 create table ttrss_user_labels2 (
405 label_id integer not null references ttrss_labels2(id) ON DELETE CASCADE,
406 article_id integer not null references ttrss_entries(id) ON DELETE CASCADE
407 );
408
409 create table ttrss_access_keys (id serial not null primary key,
410 access_key varchar(250) not null,
411 feed_id varchar(250) not null,
412 is_cat boolean not null default false,
413 owner_uid integer not null references ttrss_users(id) on delete cascade);
414
415 commit;