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