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