]> git.wh0rd.org - tt-rss.git/blob - schema/ttrss_schema_pgsql.sql
add interface/schema for inverse matching filters
[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_entry_comments;
12 drop table ttrss_user_entries;
13 drop table ttrss_entries;
14 drop table ttrss_scheduled_updates;
15 drop table ttrss_feeds;
16 drop table ttrss_feed_categories;
17 drop table ttrss_users;
18 drop table ttrss_themes;
19 drop table ttrss_sessions;
20
21 begin;
22
23 create table ttrss_themes(id serial not null primary key,
24 theme_name varchar(200) not null,
25 theme_path varchar(200) not null);
26
27 insert into ttrss_themes (theme_name, theme_path) values ('Old-skool', 'compat');
28 insert into ttrss_themes (theme_name, theme_path) values ('Graycube', 'graycube');
29 insert into ttrss_themes (theme_name, theme_path) values ('Default (Compact)', 'compact');
30
31 create table ttrss_users (id serial not null primary key,
32 login varchar(120) not null unique,
33 pwd_hash varchar(250) not null,
34 last_login timestamp default null,
35 access_level integer not null default 0,
36 email varchar(250) not null default '',
37 email_digest boolean not null default false,
38 last_digest_sent timestamp default null,
39 theme_id integer references ttrss_themes(id) default null);
40
41 insert into ttrss_users (login,pwd_hash,access_level) values ('admin',
42 'SHA1:5baa61e4c9b93f3f0682250b6cf8331b7ee68fd8', 10);
43
44 create table ttrss_feed_categories(id serial not null primary key,
45 owner_uid integer not null references ttrss_users(id) on delete cascade,
46 collapsed boolean not null default false,
47 title varchar(200) not null);
48
49 create table ttrss_feeds (id serial not null primary key,
50 owner_uid integer not null references ttrss_users(id) on delete cascade,
51 title varchar(200) not null,
52 cat_id integer references ttrss_feed_categories(id) default null,
53 feed_url varchar(250) not null,
54 icon_url varchar(250) not null default '',
55 update_interval integer not null default 0,
56 purge_interval integer not null default 0,
57 last_updated timestamp default null,
58 last_error text not null default '',
59 site_url varchar(250) not null default '',
60 auth_login varchar(250) not null default '',
61 parent_feed integer default null references ttrss_feeds(id) on delete set null,
62 private boolean not null default false,
63 auth_pass varchar(250) not null default '',
64 hidden boolean not null default false,
65 include_in_digest boolean not null default true,
66 rtl_content boolean not null default false);
67
68 create index ttrss_feeds_owner_uid_index on ttrss_feeds(owner_uid);
69
70 insert into ttrss_feeds (owner_uid,title,feed_url) values (1,'Footnotes', 'http://gnomedesktop.org/node/feed');
71 insert into ttrss_feeds (owner_uid,title,feed_url) values (1,'Latest Linux Kernel Versions','http://kernel.org/kdist/rss.xml');
72 insert into ttrss_feeds (owner_uid,title,feed_url) values (1,'RPGDot Newsfeed',
73 'http://www.rpgdot.com/team/rss/rss0.xml');
74 insert into ttrss_feeds (owner_uid,title,feed_url) values (1,'Digg.com News',
75 'http://digg.com/rss/index.xml');
76 insert into ttrss_feeds (owner_uid,title,feed_url) values (1,'Technocrat.net',
77 'http://syndication.technocrat.net/rss');
78
79 create table ttrss_entries (id serial not null primary key,
80 title text not null,
81 guid text not null unique,
82 link text not null,
83 updated timestamp not null,
84 content text not null,
85 content_hash varchar(250) not null,
86 no_orig_date boolean not null default false,
87 date_entered timestamp not null default NOW(),
88 num_comments integer not null default 0,
89 comments varchar(250) not null default '',
90 author varchar(250) not null default '');
91
92 create index ttrss_entries_guid_index on ttrss_entries(guid);
93 -- create index ttrss_entries_title_index on ttrss_entries(title);
94 -- create index ttrss_entries_date_entered_index on ttrss_entries(date_entered);
95
96 create table ttrss_user_entries (
97 int_id serial not null primary key,
98 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
99 feed_id int references ttrss_feeds(id) ON DELETE CASCADE not null,
100 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
101 marked boolean not null default false,
102 last_read timestamp,
103 unread boolean not null default true);
104
105 -- create index ttrss_user_entries_feed_id_index on ttrss_user_entries(feed_id);
106 -- create index ttrss_user_entries_owner_uid_index on ttrss_user_entries(owner_uid);
107 create index ttrss_user_entries_ref_id_index on ttrss_user_entries(ref_id);
108 create index ttrss_user_entries_feed_id on ttrss_user_entries(feed_id);
109
110 create table ttrss_entry_comments (id serial not null primary key,
111 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
112 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
113 private boolean not null default false,
114 date_entered timestamp not null);
115
116 create index ttrss_entry_comments_ref_id_index on ttrss_entry_comments(ref_id);
117 -- create index ttrss_entry_comments_owner_uid_index on ttrss_entry_comments(owner_uid);
118
119 create table ttrss_filter_types (id integer not null primary key,
120 name varchar(120) unique not null,
121 description varchar(250) not null unique);
122
123 insert into ttrss_filter_types (id,name,description) values (1, 'title', 'Title');
124 insert into ttrss_filter_types (id,name,description) values (2, 'content', 'Content');
125 insert into ttrss_filter_types (id,name,description) values (3, 'both',
126 'Title or Content');
127 insert into ttrss_filter_types (id,name,description) values (4, 'link',
128 'Link');
129
130 create table ttrss_filter_actions (id integer not null primary key,
131 name varchar(120) unique not null,
132 description varchar(250) not null unique);
133
134 insert into ttrss_filter_actions (id,name,description) values (1, 'filter',
135 'Filter article');
136
137 insert into ttrss_filter_actions (id,name,description) values (2, 'catchup',
138 'Mark as read');
139
140 insert into ttrss_filter_actions (id,name,description) values (3, 'mark',
141 'Set starred');
142
143 insert into ttrss_filter_actions (id,name,description) values (4, 'tag',
144 'Assign tags');
145
146 create table ttrss_filters (id serial not null primary key,
147 owner_uid integer not null references ttrss_users(id) on delete cascade,
148 feed_id integer references ttrss_feeds(id) on delete cascade default null,
149 filter_type integer not null references ttrss_filter_types(id),
150 reg_exp varchar(250) not null,
151 enabled boolean not null default true,
152 inverse boolean not null default false,
153 action_id integer not null default 1 references ttrss_filter_actions(id) on delete cascade,
154 action_param varchar(200) not null default '');
155
156 create table ttrss_labels (id serial not null primary key,
157 owner_uid integer not null references ttrss_users(id) on delete cascade,
158 sql_exp varchar(250) not null,
159 description varchar(250) not null);
160
161 create index ttrss_labels_owner_uid_index on ttrss_labels(owner_uid);
162
163 insert into ttrss_labels (owner_uid,sql_exp,description) values (1,'unread = true',
164 'Unread articles');
165
166 insert into ttrss_labels (owner_uid,sql_exp,description) values (1,
167 'last_read is null and unread = false', 'Updated articles');
168
169 create table ttrss_tags (id serial not null primary key,
170 tag_name varchar(250) not null,
171 owner_uid integer not null references ttrss_users(id) on delete cascade,
172 post_int_id integer references ttrss_user_entries(int_id) ON DELETE CASCADE not null);
173
174 create index ttrss_tags_owner_uid_index on ttrss_tags(owner_uid);
175
176 create table ttrss_version (schema_version int not null);
177
178 insert into ttrss_version values (13);
179
180 create table ttrss_prefs_types (id integer not null primary key,
181 type_name varchar(100) not null);
182
183 insert into ttrss_prefs_types (id, type_name) values (1, 'bool');
184 insert into ttrss_prefs_types (id, type_name) values (2, 'string');
185 insert into ttrss_prefs_types (id, type_name) values (3, 'integer');
186
187 create table ttrss_prefs_sections (id integer not null primary key,
188 section_name varchar(100) not null);
189
190 insert into ttrss_prefs_sections (id, section_name) values (1, 'General');
191 insert into ttrss_prefs_sections (id, section_name) values (2, 'Interface');
192 insert into ttrss_prefs_sections (id, section_name) values (3, 'Advanced');
193
194 create table ttrss_prefs (pref_name varchar(250) not null primary key,
195 type_id integer not null references ttrss_prefs_types(id),
196 section_id integer not null references ttrss_prefs_sections(id) default 1,
197 short_desc text not null,
198 help_text text not null default '',
199 def_value text not null);
200
201 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);
202 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);
203 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);
204 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('ENABLE_LABELS', 1, 'false', 'Enable labels',3,
205 '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.');
206
207 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);
208 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,
209 'Default limit for articles to display, any custom number you like (0 - disables).');
210
211 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,
212 'This option is useful when you are reading several planet-type aggregators with partially colliding userbase.
213 When disabled, it forces same posts from different feeds to appear only once.');
214
215 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,
216 'Link to user stylesheet to override default style, disabled if empty.');
217
218 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('ENABLE_FEED_CATS', 1, 'false', 'Enable feed categories',2);
219
220 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);
221
222 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);
223 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);
224
225 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);
226
227 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,
228 'Display expanded list of feed articles, instead of separate displays for headlines and article content');
229
230 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);
231
232 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);
233
234 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,
235 'When "Mark as read" button is clicked in toolbar, automatically open next feed with unread articles.');
236
237 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);
238
239 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);
240
241 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);
242
243 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);
244
245 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,
246 'This option enables sending daily digest of new (and unread) headlines on your configured e-mail address');
247
248 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);
249
250 create table ttrss_user_prefs (
251 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
252 pref_name varchar(250) not null references ttrss_prefs(pref_name) ON DELETE CASCADE,
253 value text not null);
254
255 create index ttrss_user_prefs_owner_uid_index on ttrss_user_prefs(owner_uid);
256 -- create index ttrss_user_prefs_value_index on ttrss_user_prefs(value);
257
258 create table ttrss_scheduled_updates (id serial not null primary key,
259 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
260 feed_id integer default null references ttrss_feeds(id) ON DELETE CASCADE,
261 entered timestamp not null default NOW());
262
263 create table ttrss_sessions (id varchar(250) unique not null primary key,
264 data text,
265 expire integer not null);
266
267 create index ttrss_sessions_expire_index on ttrss_sessions(expire);
268
269 commit;