]> git.wh0rd.org - tt-rss.git/blob - schema/ttrss_schema_pgsql.sql
add ttrss_feeds_cat_id_idx
[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 title varchar(200) not null);
56
57 create table ttrss_feeds (id serial not null primary key,
58 owner_uid integer not null references ttrss_users(id) on delete cascade,
59 title varchar(200) not null,
60 cat_id integer default null references ttrss_feed_categories(id) on delete set null,
61 feed_url text not null,
62 icon_url varchar(250) not null default '',
63 update_interval integer not null default 0,
64 purge_interval integer not null default 0,
65 last_updated timestamp default null,
66 last_error text not null default '',
67 site_url varchar(250) not null default '',
68 auth_login varchar(250) not null default '',
69 parent_feed integer default null references ttrss_feeds(id) on delete set null,
70 private boolean not null default false,
71 auth_pass varchar(250) not null default '',
72 hidden boolean not null default false,
73 include_in_digest boolean not null default true,
74 rtl_content boolean not null default false,
75 cache_images boolean not null default false,
76 last_viewed timestamp default null,
77 last_update_started timestamp default null,
78 update_method integer not null default 0,
79 always_display_enclosures boolean not null default false,
80 order_id integer not null default 0,
81 mark_unread_on_update boolean not null default false,
82 update_on_checksum_change boolean not null default false,
83 strip_images boolean not null default false,
84 pubsub_state integer not null default 0,
85 favicon_last_checked timestamp default null,
86 auth_pass_encrypted boolean not null default false);
87
88 create index ttrss_feeds_owner_uid_index on ttrss_feeds(owner_uid);
89 create index ttrss_feeds_cat_id_idx on ttrss_feeds(cat_id);
90
91 insert into ttrss_feeds (owner_uid, title, feed_url) values
92 (1, 'Tiny Tiny RSS: New Releases', 'http://tt-rss.org/releases.rss');
93
94 insert into ttrss_feeds (owner_uid, title, feed_url) values
95 (1, 'Tiny Tiny RSS: Forum', 'http://tt-rss.org/forum/rss.php');
96
97 create table ttrss_archived_feeds (id integer not null primary key,
98 owner_uid integer not null references ttrss_users(id) on delete cascade,
99 title varchar(200) not null,
100 feed_url text not null,
101 site_url varchar(250) not null default '');
102
103 create table ttrss_counters_cache (
104 feed_id integer not null,
105 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
106 updated timestamp not null,
107 value integer not null default 0);
108
109 create index ttrss_counters_cache_feed_id_idx on ttrss_counters_cache(feed_id);
110 create index ttrss_counters_cache_owner_uid_idx on ttrss_counters_cache(owner_uid);
111 create index ttrss_counters_cache_value_idx on ttrss_counters_cache(value);
112
113 create table ttrss_cat_counters_cache (
114 feed_id integer not null,
115 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
116 updated timestamp not null,
117 value integer not null default 0);
118
119 create index ttrss_cat_counters_cache_owner_uid_idx on ttrss_cat_counters_cache(owner_uid);
120
121 create table ttrss_entries (id serial not null primary key,
122 title text not null,
123 guid text not null unique,
124 link text not null,
125 updated timestamp not null,
126 content text not null,
127 content_hash varchar(250) not null,
128 no_orig_date boolean not null default false,
129 date_entered timestamp not null,
130 date_updated timestamp not null,
131 num_comments integer not null default 0,
132 comments varchar(250) not null default '',
133 author varchar(250) not null default '');
134
135 create index ttrss_entries_guid_index on ttrss_entries(guid);
136 -- create index ttrss_entries_title_index on ttrss_entries(title);
137 create index ttrss_entries_date_entered_index on ttrss_entries(date_entered);
138 create index ttrss_entries_updated_idx on ttrss_entries(updated);
139
140 create table ttrss_user_entries (
141 int_id serial not null primary key,
142 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
143 uuid varchar(200) not null,
144 feed_id int references ttrss_feeds(id) ON DELETE CASCADE,
145 orig_feed_id integer references ttrss_archived_feeds(id) ON DELETE SET NULL,
146 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
147 marked boolean not null default false,
148 published boolean not null default false,
149 tag_cache text not null,
150 label_cache text not null,
151 last_read timestamp,
152 score int not null default 0,
153 note text,
154 unread boolean not null default true);
155
156 -- create index ttrss_user_entries_feed_id_index on ttrss_user_entries(feed_id);
157 create index ttrss_user_entries_owner_uid_index on ttrss_user_entries(owner_uid);
158 create index ttrss_user_entries_ref_id_index on ttrss_user_entries(ref_id);
159 create index ttrss_user_entries_feed_id on ttrss_user_entries(feed_id);
160 create index ttrss_user_entries_unread_idx on ttrss_user_entries(unread);
161
162 create table ttrss_entry_comments (id serial not null primary key,
163 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
164 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
165 private boolean not null default false,
166 date_entered timestamp not null);
167
168 create index ttrss_entry_comments_ref_id_index on ttrss_entry_comments(ref_id);
169 -- create index ttrss_entry_comments_owner_uid_index on ttrss_entry_comments(owner_uid);
170
171 create table ttrss_filter_types (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_types (id,name,description) values (1, 'title', 'Title');
176 insert into ttrss_filter_types (id,name,description) values (2, 'content', 'Content');
177 insert into ttrss_filter_types (id,name,description) values (3, 'both',
178 'Title or Content');
179 insert into ttrss_filter_types (id,name,description) values (4, 'link',
180 'Link');
181 insert into ttrss_filter_types (id,name,description) values (5, 'date',
182 'Article Date');
183 insert into ttrss_filter_types (id,name,description) values (6, 'author', 'Author');
184 insert into ttrss_filter_types (id,name,description) values (7, 'tag', 'Article Tags');
185
186 create table ttrss_filter_actions (id integer not null primary key,
187 name varchar(120) unique not null,
188 description varchar(250) not null unique);
189
190 insert into ttrss_filter_actions (id,name,description) values (1, 'filter',
191 'Delete article');
192
193 insert into ttrss_filter_actions (id,name,description) values (2, 'catchup',
194 'Mark as read');
195
196 insert into ttrss_filter_actions (id,name,description) values (3, 'mark',
197 'Set starred');
198
199 insert into ttrss_filter_actions (id,name,description) values (4, 'tag',
200 'Assign tags');
201
202 insert into ttrss_filter_actions (id,name,description) values (5, 'publish',
203 'Publish article');
204
205 insert into ttrss_filter_actions (id,name,description) values (6, 'score',
206 'Modify score');
207
208 insert into ttrss_filter_actions (id,name,description) values (7, 'label',
209 'Assign label');
210
211 create table ttrss_filters (id serial not null primary key,
212 owner_uid integer not null references ttrss_users(id) on delete cascade,
213 feed_id integer references ttrss_feeds(id) on delete cascade default null,
214 filter_type integer not null references ttrss_filter_types(id),
215 reg_exp varchar(250) not null,
216 filter_param varchar(250) not null default '',
217 enabled boolean not null default true,
218 inverse boolean not null default false,
219 cat_filter boolean not null default false,
220 cat_id integer references ttrss_feed_categories(id) on delete cascade default null,
221 action_id integer not null default 1 references ttrss_filter_actions(id) on delete cascade,
222 action_param varchar(250) not null default '');
223
224 create table ttrss_tags (id serial not null primary key,
225 tag_name varchar(250) not null,
226 owner_uid integer not null references ttrss_users(id) on delete cascade,
227 post_int_id integer references ttrss_user_entries(int_id) ON DELETE CASCADE not null);
228
229 create index ttrss_tags_owner_uid_index on ttrss_tags(owner_uid);
230 create index ttrss_tags_post_int_id_idx on ttrss_tags(post_int_id);
231
232 create table ttrss_version (schema_version int not null);
233
234 insert into ttrss_version values (92);
235
236 create table ttrss_enclosures (id serial not null primary key,
237 content_url text not null,
238 content_type varchar(250) not null,
239 title text not null,
240 duration text not null,
241 post_id integer references ttrss_entries(id) ON DELETE cascade NOT NULL);
242
243 create index ttrss_enclosures_post_id_idx on ttrss_enclosures(post_id);
244
245 create table ttrss_settings_profiles(id serial not null primary key,
246 title varchar(250) not null,
247 owner_uid integer not null references ttrss_users(id) on delete cascade);
248
249 create table ttrss_prefs_types (id integer not null primary key,
250 type_name varchar(100) not null);
251
252 insert into ttrss_prefs_types (id, type_name) values (1, 'bool');
253 insert into ttrss_prefs_types (id, type_name) values (2, 'string');
254 insert into ttrss_prefs_types (id, type_name) values (3, 'integer');
255
256 create table ttrss_prefs_sections (id integer not null primary key,
257 section_name varchar(100) not null);
258
259 insert into ttrss_prefs_sections (id, section_name) values (1, 'General');
260 insert into ttrss_prefs_sections (id, section_name) values (2, 'Interface');
261 insert into ttrss_prefs_sections (id, section_name) values (3, 'Advanced');
262
263 create table ttrss_prefs (pref_name varchar(250) not null primary key,
264 type_id integer not null references ttrss_prefs_types(id),
265 section_id integer not null references ttrss_prefs_sections(id) default 1,
266 short_desc text not null,
267 help_text text not null default '',
268 access_level integer not null default 0,
269 def_value text not null);
270
271 create index ttrss_prefs_pref_name_idx on ttrss_prefs(pref_name);
272
273 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);
274
275 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);
276
277 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);
278
279 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.');
280
281 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('ENABLE_FEED_CATS', 1, 'true', 'Enable feed categories',2);
282
283 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);
284
285 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);
286
287 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);
288
289 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');
290
291 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);
292
293 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');
294
295 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);
296
297 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);
298
299 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');
300
301 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);
302
303 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.');
304
305 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_DEFAULT_VIEW_MODE', 2, 'adaptive', '', 1);
306
307 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_DEFAULT_VIEW_LIMIT', 3, '30', '', 1);
308
309 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_PREFS_ACTIVE_TAB', 2, '', '', 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, '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, 'When auto-detecting tags in articles these tags will not be applied (comma-separated list).');
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('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');
326
327 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);
328
329 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_DEFAULT_VIEW_ORDER_BY', 2, 'default', '', 1);
330
331 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('ENABLE_API_ACCESS', 1, 'false', 'Enable external API', 3);
332
333 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_COLLAPSED_SPECIAL', 1, 'false', '', 1);
334
335 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_COLLAPSED_LABELS', 1, 'false', '', 1);
336
337 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_COLLAPSED_UNCAT', 1, 'false', '', 1);
338
339 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_COLLAPSED_FEEDLIST', 1, 'false', '', 1);
340
341 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_MOBILE_ENABLE_CATS', 1, 'false', '', 1);
342
343 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_MOBILE_SHOW_IMAGES', 1, 'false', '', 1);
344
345 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_MOBILE_HIDE_READ', 1, 'false', '', 1);
346
347 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_MOBILE_SORT_FEEDS_UNREAD', 1, 'false', '', 1);
348
349 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_THEME_ID', 2, '0', '', 1);
350
351 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('USER_TIMEZONE', 2, 'UTC', 'User timezone', 1);
352
353 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.');
354
355 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');
356
357 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_MOBILE_BROWSE_CATS', 1, 'true', '', 1);
358
359 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');
360
361 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');
362
363 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_PREFS_SHOW_EMPTY_CATS', 1, 'false', '', 1);
364
365 create table ttrss_user_prefs (
366 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
367 pref_name varchar(250) not null references ttrss_prefs(pref_name) ON DELETE CASCADE,
368 profile integer references ttrss_settings_profiles(id) ON DELETE CASCADE,
369 value text not null);
370
371 create index ttrss_user_prefs_owner_uid_index on ttrss_user_prefs(owner_uid);
372 create index ttrss_user_prefs_pref_name_idx on ttrss_user_prefs(pref_name);
373 -- create index ttrss_user_prefs_value_index on ttrss_user_prefs(value);
374
375 create table ttrss_sessions (id varchar(250) unique not null primary key,
376 data text,
377 expire integer not null);
378
379 create index ttrss_sessions_expire_index on ttrss_sessions(expire);
380
381 create function SUBSTRING_FOR_DATE(timestamp, int, int) RETURNS text AS 'SELECT SUBSTRING(CAST($1 AS text), $2, $3)' LANGUAGE 'sql';
382
383 create table ttrss_feedbrowser_cache (
384 feed_url text not null primary key,
385 title text not null,
386 site_url text not null,
387 subscribers integer not null);
388
389 create table ttrss_labels2 (id serial not null primary key,
390 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
391 fg_color varchar(15) not null default '',
392 bg_color varchar(15) not null default '',
393 caption varchar(250) not null
394 );
395
396 create table ttrss_user_labels2 (
397 label_id integer not null references ttrss_labels2(id) ON DELETE CASCADE,
398 article_id integer not null references ttrss_entries(id) ON DELETE CASCADE
399 );
400
401 create table ttrss_access_keys (id serial not null primary key,
402 access_key varchar(250) not null,
403 feed_id varchar(250) not null,
404 is_cat boolean not null default false,
405 owner_uid integer not null references ttrss_users(id) on delete cascade);
406
407 create table ttrss_linked_instances (id serial not null primary key,
408 last_connected timestamp not null,
409 last_status_in integer not null,
410 last_status_out integer not null,
411 access_key varchar(250) not null unique,
412 access_url text not null);
413
414 create table ttrss_linked_feeds (
415 feed_url text not null,
416 site_url text not null,
417 title text not null,
418 created timestamp not null,
419 updated timestamp not null,
420 instance_id integer not null references ttrss_linked_instances(id) ON DELETE CASCADE,
421 subscribers integer not null);
422
423 commit;