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