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