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