]> git.wh0rd.org - tt-rss.git/blob - schema/ttrss_schema_pgsql.sql
add workaround for psql 8.3 stricter typechecking on SUBSTRING() (refs #201)
[tt-rss.git] / schema / ttrss_schema_pgsql.sql
1 drop table ttrss_version;
2 drop table ttrss_labels;
3 drop table ttrss_filters;
4 drop table ttrss_filter_types;
5 drop table ttrss_filter_actions;
6 drop table ttrss_user_prefs;
7 drop table ttrss_prefs;
8 drop table ttrss_prefs_types;
9 drop table ttrss_prefs_sections;
10 drop table ttrss_tags;
11 drop table ttrss_enclosures;
12 drop table ttrss_entry_comments;
13 drop table ttrss_user_entries;
14 drop table ttrss_entries;
15 drop table ttrss_scheduled_updates;
16 drop table ttrss_feeds;
17 drop table ttrss_feed_categories;
18 drop table ttrss_users;
19 drop table ttrss_themes;
20 drop table ttrss_sessions;
21 drop function SUBSTRING_FOR_DATE(timestamp, int, int);
22
23 begin;
24
25 create table ttrss_themes(id serial not null primary key,
26 theme_name varchar(200) not null,
27 theme_path varchar(200) not null);
28
29 insert into ttrss_themes (theme_name, theme_path) values ('Old-skool', 'compat');
30 insert into ttrss_themes (theme_name, theme_path) values ('Graycube', 'graycube');
31 insert into ttrss_themes (theme_name, theme_path) values ('Default (Compact)', 'compact');
32 insert into ttrss_themes (theme_name, theme_path) values ('Three-pane', '3pane');
33
34 create table ttrss_users (id serial not null primary key,
35 login varchar(120) not null unique,
36 pwd_hash varchar(250) not null,
37 last_login timestamp default null,
38 access_level integer not null default 0,
39 email varchar(250) not null default '',
40 email_digest boolean not null default false,
41 last_digest_sent timestamp default null,
42 created timestamp default null,
43 theme_id integer references ttrss_themes(id) default null);
44
45 insert into ttrss_users (login,pwd_hash,access_level) values ('admin',
46 'SHA1:5baa61e4c9b93f3f0682250b6cf8331b7ee68fd8', 10);
47
48 create table ttrss_feed_categories(id serial not null primary key,
49 owner_uid integer not null references ttrss_users(id) on delete cascade,
50 collapsed boolean not null default false,
51 title varchar(200) not null);
52
53 create table ttrss_feeds (id serial not null primary key,
54 owner_uid integer not null references ttrss_users(id) on delete cascade,
55 title varchar(200) not null,
56 cat_id integer default null references ttrss_feed_categories(id) on delete set null,
57 feed_url text not null,
58 icon_url varchar(250) not null default '',
59 update_interval integer not null default 0,
60 purge_interval integer not null default 0,
61 last_updated timestamp default null,
62 last_error text not null default '',
63 site_url varchar(250) not null default '',
64 auth_login varchar(250) not null default '',
65 parent_feed integer default null references ttrss_feeds(id) on delete set null,
66 private boolean not null default false,
67 auth_pass varchar(250) not null default '',
68 hidden boolean not null default false,
69 include_in_digest boolean not null default true,
70 rtl_content boolean not null default false,
71 cache_images boolean not null default false,
72 last_viewed timestamp default null,
73 last_update_started timestamp default null,
74 update_method integer not null default 0,
75 auth_pass_encrypted boolean not null default false);
76
77 create index ttrss_feeds_owner_uid_index on ttrss_feeds(owner_uid);
78
79 insert into ttrss_feeds (owner_uid, title, feed_url) values
80 (1, 'Tiny Tiny RSS: New Releases', 'http://tt-rss.spb.ru/releases.rss');
81
82 insert into ttrss_feeds (owner_uid, title, feed_url) values
83 (1, 'Tiny Tiny RSS: Forum', 'http://tt-rss.spb.ru/forum/rss.php');
84
85 create table ttrss_entries (id serial not null primary key,
86 title text not null,
87 guid text not null unique,
88 link text not null,
89 updated timestamp not null,
90 content text not null,
91 content_hash varchar(250) not null,
92 no_orig_date boolean not null default false,
93 date_entered timestamp not null default NOW(),
94 num_comments integer not null default 0,
95 comments varchar(250) not null default '',
96 author varchar(250) not null default '');
97
98 create index ttrss_entries_guid_index on ttrss_entries(guid);
99 -- create index ttrss_entries_title_index on ttrss_entries(title);
100 create index ttrss_entries_date_entered_index on ttrss_entries(date_entered);
101
102 create table ttrss_user_entries (
103 int_id serial not null primary key,
104 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
105 feed_id int references ttrss_feeds(id) ON DELETE CASCADE not null,
106 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
107 marked boolean not null default false,
108 published boolean not null default false,
109 last_read timestamp,
110 unread boolean not null default true);
111
112 -- create index ttrss_user_entries_feed_id_index on ttrss_user_entries(feed_id);
113 -- create index ttrss_user_entries_owner_uid_index on ttrss_user_entries(owner_uid);
114 create index ttrss_user_entries_ref_id_index on ttrss_user_entries(ref_id);
115 create index ttrss_user_entries_feed_id on ttrss_user_entries(feed_id);
116
117 create table ttrss_entry_comments (id serial not null primary key,
118 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
119 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
120 private boolean not null default false,
121 date_entered timestamp not null);
122
123 create index ttrss_entry_comments_ref_id_index on ttrss_entry_comments(ref_id);
124 -- create index ttrss_entry_comments_owner_uid_index on ttrss_entry_comments(owner_uid);
125
126 create table ttrss_filter_types (id integer not null primary key,
127 name varchar(120) unique not null,
128 description varchar(250) not null unique);
129
130 insert into ttrss_filter_types (id,name,description) values (1, 'title', 'Title');
131 insert into ttrss_filter_types (id,name,description) values (2, 'content', 'Content');
132 insert into ttrss_filter_types (id,name,description) values (3, 'both',
133 'Title or Content');
134 insert into ttrss_filter_types (id,name,description) values (4, 'link',
135 'Link');
136
137 create table ttrss_filter_actions (id integer not null primary key,
138 name varchar(120) unique not null,
139 description varchar(250) not null unique);
140
141 insert into ttrss_filter_actions (id,name,description) values (1, 'filter',
142 'Filter article');
143
144 insert into ttrss_filter_actions (id,name,description) values (2, 'catchup',
145 'Mark as read');
146
147 insert into ttrss_filter_actions (id,name,description) values (3, 'mark',
148 'Set starred');
149
150 insert into ttrss_filter_actions (id,name,description) values (4, 'tag',
151 'Assign tags');
152
153 insert into ttrss_filter_actions (id,name,description) values (5, 'publish',
154 'Publish article');
155
156 create table ttrss_filters (id serial not null primary key,
157 owner_uid integer not null references ttrss_users(id) on delete cascade,
158 feed_id integer references ttrss_feeds(id) on delete cascade default null,
159 filter_type integer not null references ttrss_filter_types(id),
160 reg_exp varchar(250) not null,
161 enabled boolean not null default true,
162 inverse boolean not null default false,
163 action_id integer not null default 1 references ttrss_filter_actions(id) on delete cascade,
164 action_param varchar(250) not null default '');
165
166 create table ttrss_labels (id serial not null primary key,
167 owner_uid integer not null references ttrss_users(id) on delete cascade,
168 sql_exp varchar(250) not null,
169 description varchar(250) not null);
170
171 create index ttrss_labels_owner_uid_index on ttrss_labels(owner_uid);
172
173 insert into ttrss_labels (owner_uid,sql_exp,description) values (1,'unread = true',
174 'Unread articles');
175
176 insert into ttrss_labels (owner_uid,sql_exp,description) values (1,
177 'last_read is null and unread = false', 'Updated articles');
178
179 create table ttrss_tags (id serial not null primary key,
180 tag_name varchar(250) not null,
181 owner_uid integer not null references ttrss_users(id) on delete cascade,
182 post_int_id integer references ttrss_user_entries(int_id) ON DELETE CASCADE not null);
183
184 create index ttrss_tags_owner_uid_index on ttrss_tags(owner_uid);
185
186 create table ttrss_version (schema_version int not null);
187
188 insert into ttrss_version values (35);
189
190 create table ttrss_enclosures (id serial not null primary key,
191 content_url text not null,
192 content_type varchar(250) not null,
193 title text not null,
194 duration text not null,
195 post_id integer references ttrss_entries(id) ON DELETE cascade NOT NULL);
196
197 create table ttrss_prefs_types (id integer not null primary key,
198 type_name varchar(100) not null);
199
200 insert into ttrss_prefs_types (id, type_name) values (1, 'bool');
201 insert into ttrss_prefs_types (id, type_name) values (2, 'string');
202 insert into ttrss_prefs_types (id, type_name) values (3, 'integer');
203
204 create table ttrss_prefs_sections (id integer not null primary key,
205 section_name varchar(100) not null);
206
207 insert into ttrss_prefs_sections (id, section_name) values (1, 'General');
208 insert into ttrss_prefs_sections (id, section_name) values (2, 'Interface');
209 insert into ttrss_prefs_sections (id, section_name) values (3, 'Advanced');
210
211 create table ttrss_prefs (pref_name varchar(250) not null primary key,
212 type_id integer not null references ttrss_prefs_types(id),
213 section_id integer not null references ttrss_prefs_sections(id) default 1,
214 short_desc text not null,
215 help_text text not null default '',
216 access_level integer not null default 0,
217 def_value text not null);
218
219 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('ENABLE_FEED_ICONS', 1, 'true', 'Enable icons in feedlist',3);
220 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);
221 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);
222 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('ENABLE_LABELS', 1, 'false', 'Enable labels',3,
223 '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.');
224
225 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);
226 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,
227 'Default limit for articles to display, any custom number you like (0 - disables).');
228
229 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,
230 '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.');
231
232 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,
233 'Link to user stylesheet to override default style, disabled if empty.');
234
235 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('ENABLE_FEED_CATS', 1, 'false', 'Enable feed categories',2);
236
237 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);
238
239 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);
240 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);
241
242 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);
243
244 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,
245 'Display expanded list of feed articles, instead of separate displays for headlines and article content');
246
247 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);
248
249 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);
250
251 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,
252 'When "Mark as read" button is clicked in toolbar, automatically open next feed with unread articles.');
253
254 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);
255
256 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);
257
258 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);
259
260 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);
261
262 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,
263 'This option enables sending daily digest of new (and unread) headlines on your configured e-mail address');
264
265 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);
266
267 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,
268 'This option enables marking articles as read automatically in combined mode while you scroll article list.');
269
270 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_DEFAULT_VIEW_MODE', 2, 'adaptive', '', 1);
271
272 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_DEFAULT_VIEW_LIMIT', 3, '30', '', 1);
273
274 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_PREFS_ACTIVE_TAB', 2, '', '', 1);
275
276 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_INFOBOX_DISABLE_OVERLAY', 1, 'false', '', 1);
277
278 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,
279 'Strip all but most common HTML tags when reading articles.');
280
281 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,
282 'When auto-detecting tags in articles these tags will not be applied (comma-separated list).');
283
284 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('ENABLE_SEARCH_TOOLBAR', 1, 'false', 'Enable search toolbar',2);
285
286 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_PREFS_ENABLE_PAGINATION', 2, '', '', 1);
287
288 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('_PREFS_PUBLISH_KEY', 2, '', '', 1);
289
290 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);
291
292 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);
293
294 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);
295
296 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('PURGE_UNREAD_ARTICLES', 1, 'true', 'Purge unread articles',3);
297
298 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);
299
300 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.');
301
302 create table ttrss_user_prefs (
303 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
304 pref_name varchar(250) not null references ttrss_prefs(pref_name) ON DELETE CASCADE,
305 value text not null);
306
307 create index ttrss_user_prefs_owner_uid_index on ttrss_user_prefs(owner_uid);
308 -- create index ttrss_user_prefs_value_index on ttrss_user_prefs(value);
309
310 create table ttrss_scheduled_updates (id serial not null primary key,
311 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
312 feed_id integer default null references ttrss_feeds(id) ON DELETE CASCADE,
313 entered timestamp not null default NOW());
314
315 create table ttrss_sessions (id varchar(250) unique not null primary key,
316 data text,
317 expire integer not null);
318
319 create index ttrss_sessions_expire_index on ttrss_sessions(expire);
320
321 create function SUBSTRING_FOR_DATE(timestamp, int, int) RETURNS text AS 'SELECT SUBSTRING(CAST($1 AS text), $2, $3)' LANGUAGE 'sql';
322
323 commit;