]> git.wh0rd.org - tt-rss.git/blob - schema/ttrss_schema_pgsql.sql
more fts stuff for simple index
[tt-rss.git] / schema / ttrss_schema_pgsql.sql
1 drop table if exists ttrss_error_log;
2 drop table if exists ttrss_plugin_storage;
3 drop table if exists ttrss_linked_feeds;
4 drop table if exists ttrss_linked_instances;
5 drop table if exists ttrss_access_keys;
6 drop table if exists ttrss_user_labels2;
7 drop table if exists ttrss_labels2;
8 drop table if exists ttrss_feedbrowser_cache;
9 drop table if exists ttrss_version;
10 drop table if exists ttrss_labels;
11 drop table if exists ttrss_filters2_rules;
12 drop table if exists ttrss_filters2_actions;
13 drop table if exists ttrss_filters2;
14 drop table if exists ttrss_filters;
15 drop table if exists ttrss_filter_types;
16 drop table if exists ttrss_filter_actions;
17 drop table if exists ttrss_user_prefs;
18 drop table if exists ttrss_prefs;
19 drop table if exists ttrss_prefs_types;
20 drop table if exists ttrss_prefs_sections;
21 drop table if exists ttrss_tags;
22 drop table if exists ttrss_enclosures;
23 drop table if exists ttrss_settings_profiles;
24 drop table if exists ttrss_entry_comments;
25 drop table if exists ttrss_user_entries;
26 drop table if exists ttrss_entries;
27 drop table if exists ttrss_scheduled_updates;
28 drop table if exists ttrss_counters_cache;
29 drop table if exists ttrss_cat_counters_cache;
30 drop table if exists ttrss_archived_feeds;
31 drop table if exists ttrss_feeds;
32 drop table if exists ttrss_feed_categories;
33 drop table if exists ttrss_users;
34 drop table if exists ttrss_themes;
35 drop table if exists ttrss_sessions;
36 drop function if exists SUBSTRING_FOR_DATE(timestamp, int, int);
37
38 begin;
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 full_name varchar(250) not null default '',
47 email_digest boolean not null default false,
48 last_digest_sent timestamp default null,
49 salt varchar(250) not null default '',
50 twitter_oauth text default null,
51 otp_enabled boolean not null default false,
52 resetpass_token varchar(250) default null,
53 created timestamp default null);
54
55 insert into ttrss_users (login,pwd_hash,access_level) values ('admin',
56 'SHA1:5baa61e4c9b93f3f0682250b6cf8331b7ee68fd8', 10);
57
58 create table ttrss_feed_categories(id serial not null primary key,
59 owner_uid integer not null references ttrss_users(id) on delete cascade,
60 collapsed boolean not null default false,
61 order_id integer not null default 0,
62 view_settings varchar(250) not null default '',
63 parent_cat integer references ttrss_feed_categories(id) on delete set null,
64 title varchar(200) not null);
65
66 create table ttrss_feeds (id serial not null primary key,
67 owner_uid integer not null references ttrss_users(id) on delete cascade,
68 title varchar(200) not null,
69 cat_id integer default null references ttrss_feed_categories(id) on delete set null,
70 feed_url text not null,
71 icon_url varchar(250) not null default '',
72 update_interval integer not null default 0,
73 purge_interval integer not null default 0,
74 last_updated timestamp default null,
75 last_error text not null default '',
76 favicon_avg_color varchar(11) default null,
77 site_url varchar(250) not null default '',
78 auth_login varchar(250) not null default '',
79 parent_feed integer default null references ttrss_feeds(id) on delete set null,
80 private boolean not null default false,
81 auth_pass varchar(250) not null default '',
82 hidden boolean not null default false,
83 include_in_digest boolean not null default true,
84 rtl_content boolean not null default false,
85 cache_images boolean not null default false,
86 hide_images boolean not null default false,
87 cache_content boolean not null default false,
88 last_viewed timestamp default null,
89 last_update_started timestamp default null,
90 update_method integer not null default 0,
91 always_display_enclosures boolean not null default false,
92 order_id integer not null default 0,
93 mark_unread_on_update boolean not null default false,
94 update_on_checksum_change boolean not null default false,
95 strip_images boolean not null default false,
96 view_settings varchar(250) not null default '',
97 pubsub_state integer not null default 0,
98 favicon_last_checked timestamp default null,
99 auth_pass_encrypted boolean not null default false);
100
101 create index ttrss_feeds_owner_uid_index on ttrss_feeds(owner_uid);
102 create index ttrss_feeds_cat_id_idx on ttrss_feeds(cat_id);
103
104 insert into ttrss_feeds (owner_uid, title, feed_url) values
105 (1, 'Tiny Tiny RSS: Forum', 'http://tt-rss.org/forum/rss.php');
106
107 create table ttrss_archived_feeds (id integer not null primary key,
108 owner_uid integer not null references ttrss_users(id) on delete cascade,
109 title varchar(200) not null,
110 feed_url text not null,
111 site_url varchar(250) not null default '');
112
113 create table ttrss_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_counters_cache_feed_id_idx on ttrss_counters_cache(feed_id);
120 create index ttrss_counters_cache_owner_uid_idx on ttrss_counters_cache(owner_uid);
121 create index ttrss_counters_cache_value_idx on ttrss_counters_cache(value);
122
123 create table ttrss_cat_counters_cache (
124 feed_id integer not null,
125 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
126 updated timestamp not null,
127 value integer not null default 0);
128
129 create index ttrss_cat_counters_cache_owner_uid_idx on ttrss_cat_counters_cache(owner_uid);
130
131 create table ttrss_entries (id serial not null primary key,
132 title text not null,
133 guid text not null unique,
134 link text not null,
135 updated timestamp not null,
136 content text not null,
137 content_hash varchar(250) not null,
138 cached_content text,
139 no_orig_date boolean not null default false,
140 date_entered timestamp not null,
141 date_updated timestamp not null,
142 num_comments integer not null default 0,
143 comments varchar(250) not null default '',
144 plugin_data text,
145 tsvector_combined tsvector,
146 lang varchar(2),
147 author varchar(250) not null default '');
148
149 -- create index ttrss_entries_title_index on ttrss_entries(title);
150 create index ttrss_entries_date_entered_index on ttrss_entries(date_entered);
151 create index ttrss_entries_updated_idx on ttrss_entries(updated);
152 create index ttrss_entries_tsvector_combined_idx on ttrss_entries using gin(tsvector_combined);
153
154 create table ttrss_user_entries (
155 int_id serial not null primary key,
156 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
157 uuid varchar(200) not null,
158 feed_id int references ttrss_feeds(id) ON DELETE CASCADE,
159 orig_feed_id integer references ttrss_archived_feeds(id) ON DELETE SET NULL,
160 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
161 marked boolean not null default false,
162 published boolean not null default false,
163 tag_cache text not null,
164 label_cache text not null,
165 last_read timestamp,
166 score int not null default 0,
167 last_marked timestamp,
168 last_published timestamp,
169 note text,
170 unread boolean not null default true);
171
172 -- create index ttrss_user_entries_feed_id_index on ttrss_user_entries(feed_id);
173 create index ttrss_user_entries_owner_uid_index on ttrss_user_entries(owner_uid);
174 create index ttrss_user_entries_ref_id_index on ttrss_user_entries(ref_id);
175 create index ttrss_user_entries_feed_id on ttrss_user_entries(feed_id);
176 create index ttrss_user_entries_unread_idx on ttrss_user_entries(unread);
177
178 create table ttrss_entry_comments (id serial not null primary key,
179 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
180 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
181 private boolean not null default false,
182 date_entered timestamp not null);
183
184 create index ttrss_entry_comments_ref_id_index on ttrss_entry_comments(ref_id);
185 -- create index ttrss_entry_comments_owner_uid_index on ttrss_entry_comments(owner_uid);
186
187 create table ttrss_filter_types (id integer not null primary key,
188 name varchar(120) unique not null,
189 description varchar(250) not null unique);
190
191 insert into ttrss_filter_types (id,name,description) values (1, 'title', 'Title');
192 insert into ttrss_filter_types (id,name,description) values (2, 'content', 'Content');
193 insert into ttrss_filter_types (id,name,description) values (3, 'both',
194 'Title or Content');
195 insert into ttrss_filter_types (id,name,description) values (4, 'link',
196 'Link');
197 insert into ttrss_filter_types (id,name,description) values (5, 'date',
198 'Article Date');
199 insert into ttrss_filter_types (id,name,description) values (6, 'author', 'Author');
200 insert into ttrss_filter_types (id,name,description) values (7, 'tag', 'Article Tags');
201
202 create table ttrss_filter_actions (id integer not null primary key,
203 name varchar(120) unique not null,
204 description varchar(250) not null unique);
205
206 insert into ttrss_filter_actions (id,name,description) values (1, 'filter',
207 'Delete article');
208
209 insert into ttrss_filter_actions (id,name,description) values (2, 'catchup',
210 'Mark as read');
211
212 insert into ttrss_filter_actions (id,name,description) values (3, 'mark',
213 'Set starred');
214
215 insert into ttrss_filter_actions (id,name,description) values (4, 'tag',
216 'Assign tags');
217
218 insert into ttrss_filter_actions (id,name,description) values (5, 'publish',
219 'Publish article');
220
221 insert into ttrss_filter_actions (id,name,description) values (6, 'score',
222 'Modify score');
223
224 insert into ttrss_filter_actions (id,name,description) values (7, 'label',
225 'Assign label');
226
227 insert into ttrss_filter_actions (id,name,description) values (8, 'stop',
228 'Stop / Do nothing');
229
230 create table ttrss_filters2(id serial not null primary key,
231 owner_uid integer not null references ttrss_users(id) on delete cascade,
232 match_any_rule boolean not null default false,
233 inverse boolean not null default false,
234 title varchar(250) not null default '',
235 order_id integer not null default 0,
236 enabled boolean not null default true);
237
238 create table ttrss_filters2_rules(id serial not null primary key,
239 filter_id integer not null references ttrss_filters2(id) on delete cascade,
240 reg_exp varchar(250) not null,
241 inverse boolean not null default false,
242 filter_type integer not null references ttrss_filter_types(id),
243 feed_id integer references ttrss_feeds(id) on delete cascade default null,
244 cat_id integer references ttrss_feed_categories(id) on delete cascade default null,
245 cat_filter boolean not null default false);
246
247 create table ttrss_filters2_actions(id serial not null primary key,
248 filter_id integer not null references ttrss_filters2(id) on delete cascade,
249 action_id integer not null default 1 references ttrss_filter_actions(id) on delete cascade,
250 action_param varchar(250) not null default '');
251
252 create table ttrss_tags (id serial not null primary key,
253 tag_name varchar(250) not null,
254 owner_uid integer not null references ttrss_users(id) on delete cascade,
255 post_int_id integer references ttrss_user_entries(int_id) ON DELETE CASCADE not null);
256
257 create index ttrss_tags_owner_uid_index on ttrss_tags(owner_uid);
258 create index ttrss_tags_post_int_id_idx on ttrss_tags(post_int_id);
259
260 create table ttrss_version (schema_version int not null);
261
262 insert into ttrss_version values (127);
263
264 create table ttrss_enclosures (id serial not null primary key,
265 content_url text not null,
266 content_type varchar(250) not null,
267 title text not null,
268 duration text not null,
269 width integer not null default 0,
270 height integer not null default 0,
271 post_id integer references ttrss_entries(id) ON DELETE cascade NOT NULL);
272
273 create index ttrss_enclosures_post_id_idx on ttrss_enclosures(post_id);
274
275 create table ttrss_settings_profiles(id serial not null primary key,
276 title varchar(250) not null,
277 owner_uid integer not null references ttrss_users(id) on delete cascade);
278
279 create table ttrss_prefs_types (id integer not null primary key,
280 type_name varchar(100) not null);
281
282 insert into ttrss_prefs_types (id, type_name) values (1, 'bool');
283 insert into ttrss_prefs_types (id, type_name) values (2, 'string');
284 insert into ttrss_prefs_types (id, type_name) values (3, 'integer');
285
286 create table ttrss_prefs_sections (id integer not null primary key,
287 order_id integer not null,
288 section_name varchar(100) not null);
289
290 insert into ttrss_prefs_sections (id, section_name, order_id) values (1, 'General', 0);
291 insert into ttrss_prefs_sections (id, section_name, order_id) values (2, 'Interface', 1);
292 insert into ttrss_prefs_sections (id, section_name, order_id) values (3, 'Advanced', 3);
293 insert into ttrss_prefs_sections (id, section_name, order_id) values (4, 'Digest', 2);
294
295 create table ttrss_prefs (pref_name varchar(250) not null primary key,
296 type_id integer not null references ttrss_prefs_types(id),
297 section_id integer not null default 1 references ttrss_prefs_sections(id),
298 access_level integer not null default 0,
299 def_value text not null);
300
301 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('PURGE_OLD_DAYS', 3, '60', 1);
302 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DEFAULT_UPDATE_INTERVAL', 3, '30', 1);
303 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DEFAULT_ARTICLE_LIMIT', 3, '30', 2);
304 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('ALLOW_DUPLICATE_POSTS', 1, 'false', 1);
305 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('ENABLE_FEED_CATS', 1, 'true', 2);
306 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('SHOW_CONTENT_PREVIEW', 1, 'true', 2);
307 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('SHORT_DATE_FORMAT', 2, 'M d, G:i', 3);
308 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('LONG_DATE_FORMAT', 2, 'D, M d Y - G:i', 3);
309 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('COMBINED_DISPLAY_MODE', 1, 'true', 2);
310 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('HIDE_READ_FEEDS', 1, 'false', 2);
311 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('ON_CATCHUP_SHOW_NEXT_FEED', 1, 'false', 2);
312 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('FEEDS_SORT_BY_UNREAD', 1, 'false', 2);
313 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('REVERSE_HEADLINES', 1, 'false', 2);
314 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DIGEST_ENABLE', 1, 'false', 4);
315 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('CONFIRM_FEED_CATCHUP', 1, 'true', 2);
316 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('CDM_AUTO_CATCHUP', 1, 'false', 2);
317 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_DEFAULT_VIEW_MODE', 2, 'adaptive', 1);
318 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_DEFAULT_VIEW_LIMIT', 3, '30', 1);
319 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_PREFS_ACTIVE_TAB', 2, '', 1);
320 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('STRIP_UNSAFE_TAGS', 1, 'true', 3);
321 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('BLACKLISTED_TAGS', 2, 'main, generic, misc, uncategorized, blog, blogroll, general, news', 3);
322 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('FRESH_ARTICLE_MAX_AGE', 3, '24', 2);
323 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DIGEST_CATCHUP', 1, 'false', 4);
324 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('CDM_EXPANDED', 1, 'true', 2);
325 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('PURGE_UNREAD_ARTICLES', 1, 'true', 3);
326 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('HIDE_READ_SHOWS_SPECIAL', 1, 'true', 2);
327 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('VFEED_GROUP_BY_FEED', 1, 'false', 2);
328 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('STRIP_IMAGES', 1, 'false', 2);
329 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_DEFAULT_VIEW_ORDER_BY', 2, 'default', 1);
330 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('ENABLE_API_ACCESS', 1, 'false', 1);
331 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_COLLAPSED_SPECIAL', 1, 'false', 1);
332 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_COLLAPSED_LABELS', 1, 'false', 1);
333 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_COLLAPSED_UNCAT', 1, 'false', 1);
334 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_COLLAPSED_FEEDLIST', 1, 'false', 1);
335 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_ENABLE_CATS', 1, 'false', 1);
336 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_SHOW_IMAGES', 1, 'false', 1);
337 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_HIDE_READ', 1, 'false', 1);
338 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_SORT_FEEDS_UNREAD', 1, 'false', 1);
339 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_THEME_ID', 2, '0', 1);
340 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('USER_TIMEZONE', 2, 'Automatic', 1);
341 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('USER_STYLESHEET', 2, '', 2);
342 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('SORT_HEADLINES_BY_FEED_DATE', 1, 'false', 2);
343 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_BROWSE_CATS', 1, 'true', 1);
344 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('SSL_CERT_SERIAL', 2, '', 3);
345 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('DIGEST_PREFERRED_TIME', 2, '00:00', 4);
346 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_PREFS_SHOW_EMPTY_CATS', 1, 'false', 1);
347 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_DEFAULT_INCLUDE_CHILDREN', 1, 'false', 1);
348 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('AUTO_ASSIGN_LABELS', 1, 'false', 3);
349 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_ENABLED_PLUGINS', 2, '', 1);
350 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('_MOBILE_REVERSE_HEADLINES', 1, 'false', 1);
351 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('USER_CSS_THEME', 2, '', 2);
352 insert into ttrss_prefs (pref_name,type_id,def_value,section_id) values('USER_LANGUAGE', 2, '', 2);
353
354 update ttrss_prefs set access_level = 1 where pref_name in ('ON_CATCHUP_SHOW_NEXT_FEED',
355 'SORT_HEADLINES_BY_FEED_DATE',
356 'VFEED_GROUP_BY_FEED',
357 'FRESH_ARTICLE_MAX_AGE',
358 'CDM_EXPANDED',
359 'SHOW_CONTENT_PREVIEW',
360 'AUTO_ASSIGN_LABELS',
361 'HIDE_READ_SHOWS_SPECIAL');
362
363 create table ttrss_user_prefs (
364 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
365 pref_name varchar(250) not null references ttrss_prefs(pref_name) ON DELETE CASCADE,
366 profile integer references ttrss_settings_profiles(id) ON DELETE CASCADE,
367 value text not null);
368
369 create index ttrss_user_prefs_owner_uid_index on ttrss_user_prefs(owner_uid);
370 create index ttrss_user_prefs_pref_name_idx on ttrss_user_prefs(pref_name);
371 -- create index ttrss_user_prefs_value_index on ttrss_user_prefs(value);
372
373 create table ttrss_sessions (id varchar(250) not null primary key,
374 data text,
375 expire integer not null);
376
377 create index ttrss_sessions_expire_index on ttrss_sessions(expire);
378
379 create function SUBSTRING_FOR_DATE(timestamp, int, int) RETURNS text AS 'SELECT SUBSTRING(CAST($1 AS text), $2, $3)' LANGUAGE 'sql';
380
381 create table ttrss_feedbrowser_cache (
382 feed_url text not null primary key,
383 title text not null,
384 site_url text not null,
385 subscribers integer not null);
386
387 create table ttrss_labels2 (id serial not null primary key,
388 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
389 fg_color varchar(15) not null default '',
390 bg_color varchar(15) not null default '',
391 caption varchar(250) not null
392 );
393
394 create table ttrss_user_labels2 (
395 label_id integer not null references ttrss_labels2(id) ON DELETE CASCADE,
396 article_id integer not null references ttrss_entries(id) ON DELETE CASCADE
397 );
398
399 create table ttrss_access_keys (id serial not null primary key,
400 access_key varchar(250) not null,
401 feed_id varchar(250) not null,
402 is_cat boolean not null default false,
403 owner_uid integer not null references ttrss_users(id) on delete cascade);
404
405 create table ttrss_linked_instances (id serial not null primary key,
406 last_connected timestamp not null,
407 last_status_in integer not null,
408 last_status_out integer not null,
409 access_key varchar(250) not null unique,
410 access_url text not null);
411
412 create table ttrss_linked_feeds (
413 feed_url text not null,
414 site_url text not null,
415 title text not null,
416 created timestamp not null,
417 updated timestamp not null,
418 instance_id integer not null references ttrss_linked_instances(id) ON DELETE CASCADE,
419 subscribers integer not null);
420
421 create table ttrss_plugin_storage (
422 id serial not null primary key,
423 name varchar(100) not null,
424 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
425 content text not null);
426
427 create table ttrss_error_log(
428 id serial not null primary key,
429 owner_uid integer references ttrss_users(id) ON DELETE SET NULL,
430 errno integer not null,
431 errstr text not null,
432 filename text not null,
433 lineno integer not null,
434 context text not null,
435 created_at timestamp not null);
436
437 commit;