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