]> git.wh0rd.org - tt-rss.git/blob - schema/ttrss_schema_pgsql.sql
add fields for daily email digest to ttrss_users
[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 rtl_content boolean not null default false);
64
65 create index ttrss_feeds_owner_uid_index on ttrss_feeds(owner_uid);
66
67 insert into ttrss_feeds (owner_uid,title,feed_url) values (1,'Footnotes', 'http://gnomedesktop.org/node/feed');
68 insert into ttrss_feeds (owner_uid,title,feed_url) values (1,'Latest Linux Kernel Versions','http://kernel.org/kdist/rss.xml');
69 insert into ttrss_feeds (owner_uid,title,feed_url) values (1,'RPGDot Newsfeed',
70 'http://www.rpgdot.com/team/rss/rss0.xml');
71 insert into ttrss_feeds (owner_uid,title,feed_url) values (1,'Digg.com News',
72 'http://digg.com/rss/index.xml');
73 insert into ttrss_feeds (owner_uid,title,feed_url) values (1,'Technocrat.net',
74 'http://syndication.technocrat.net/rss');
75
76 create table ttrss_entries (id serial not null primary key,
77 title text not null,
78 guid text not null unique,
79 link text not null,
80 updated timestamp not null,
81 content text not null,
82 content_hash varchar(250) not null,
83 no_orig_date boolean not null default false,
84 date_entered timestamp not null default NOW(),
85 num_comments integer not null default 0,
86 comments varchar(250) not null default '',
87 author varchar(250) not null default '');
88
89 create index ttrss_entries_guid_index on ttrss_entries(guid);
90 -- create index ttrss_entries_title_index on ttrss_entries(title);
91 -- create index ttrss_entries_date_entered_index on ttrss_entries(date_entered);
92
93 create table ttrss_user_entries (
94 int_id serial not null primary key,
95 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
96 feed_id int references ttrss_feeds(id) ON DELETE CASCADE not null,
97 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
98 marked boolean not null default false,
99 last_read timestamp,
100 unread boolean not null default true);
101
102 -- create index ttrss_user_entries_feed_id_index on ttrss_user_entries(feed_id);
103 -- create index ttrss_user_entries_owner_uid_index on ttrss_user_entries(owner_uid);
104 create index ttrss_user_entries_ref_id_index on ttrss_user_entries(ref_id);
105 create index ttrss_user_entries_feed_id on ttrss_user_entries(feed_id);
106
107 create table ttrss_entry_comments (id serial not null primary key,
108 ref_id integer not null references ttrss_entries(id) ON DELETE CASCADE,
109 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
110 private boolean not null default false,
111 date_entered timestamp not null);
112
113 create index ttrss_entry_comments_ref_id_index on ttrss_entry_comments(ref_id);
114 -- create index ttrss_entry_comments_owner_uid_index on ttrss_entry_comments(owner_uid);
115
116 create table ttrss_filter_types (id integer not null primary key,
117 name varchar(120) unique not null,
118 description varchar(250) not null unique);
119
120 insert into ttrss_filter_types (id,name,description) values (1, 'title', 'Title');
121 insert into ttrss_filter_types (id,name,description) values (2, 'content', 'Content');
122 insert into ttrss_filter_types (id,name,description) values (3, 'both',
123 'Title or Content');
124 insert into ttrss_filter_types (id,name,description) values (4, 'link',
125 'Link');
126
127 create table ttrss_filter_actions (id integer not null primary key,
128 name varchar(120) unique not null,
129 description varchar(250) not null unique);
130
131 insert into ttrss_filter_actions (id,name,description) values (1, 'filter',
132 'Filter article');
133
134 insert into ttrss_filter_actions (id,name,description) values (2, 'catchup',
135 'Mark as read');
136
137 insert into ttrss_filter_actions (id,name,description) values (3, 'mark',
138 'Set starred');
139
140 create table ttrss_filters (id serial not null primary key,
141 owner_uid integer not null references ttrss_users(id) on delete cascade,
142 feed_id integer references ttrss_feeds(id) on delete cascade default null,
143 filter_type integer not null references ttrss_filter_types(id),
144 reg_exp varchar(250) not null,
145 action_id integer not null default 1 references ttrss_filter_actions(id) on delete cascade);
146
147 create table ttrss_labels (id serial not null primary key,
148 owner_uid integer not null references ttrss_users(id) on delete cascade,
149 sql_exp varchar(250) not null,
150 description varchar(250) not null);
151
152 create index ttrss_labels_owner_uid_index on ttrss_labels(owner_uid);
153
154 insert into ttrss_labels (owner_uid,sql_exp,description) values (1,'unread = true',
155 'Unread articles');
156
157 insert into ttrss_labels (owner_uid,sql_exp,description) values (1,
158 'last_read is null and unread = false', 'Updated articles');
159
160 create table ttrss_tags (id serial not null primary key,
161 tag_name varchar(250) not null,
162 owner_uid integer not null references ttrss_users(id) on delete cascade,
163 post_int_id integer references ttrss_user_entries(int_id) ON DELETE CASCADE not null);
164
165 create index ttrss_tags_owner_uid_index on ttrss_tags(owner_uid);
166
167 create table ttrss_version (schema_version int not null);
168
169 insert into ttrss_version values (9);
170
171 create table ttrss_prefs_types (id integer not null primary key,
172 type_name varchar(100) not null);
173
174 insert into ttrss_prefs_types (id, type_name) values (1, 'bool');
175 insert into ttrss_prefs_types (id, type_name) values (2, 'string');
176 insert into ttrss_prefs_types (id, type_name) values (3, 'integer');
177
178 create table ttrss_prefs_sections (id integer not null primary key,
179 section_name varchar(100) not null);
180
181 insert into ttrss_prefs_sections (id, section_name) values (1, 'General');
182 insert into ttrss_prefs_sections (id, section_name) values (2, 'Interface');
183 insert into ttrss_prefs_sections (id, section_name) values (3, 'Advanced');
184
185 create table ttrss_prefs (pref_name varchar(250) not null primary key,
186 type_id integer not null references ttrss_prefs_types(id),
187 section_id integer not null references ttrss_prefs_sections(id) default 1,
188 short_desc text not null,
189 help_text text not null default '',
190 def_value text not null);
191
192 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);
193 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);
194 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);
195 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id,help_text) values('ENABLE_LABELS', 1, 'false', 'Enable labels',3,
196 '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.');
197
198 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);
199 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('DISPLAY_HEADER', 1, 'true', 'Display header',2);
200 insert into ttrss_prefs (pref_name,type_id,def_value,short_desc,section_id) values('DISPLAY_FOOTER', 1, 'true', 'Display footer',2);
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 create table ttrss_user_prefs (
242 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
243 pref_name varchar(250) not null references ttrss_prefs(pref_name) ON DELETE CASCADE,
244 value text not null);
245
246 create index ttrss_user_prefs_owner_uid_index on ttrss_user_prefs(owner_uid);
247 -- create index ttrss_user_prefs_value_index on ttrss_user_prefs(value);
248
249 create table ttrss_scheduled_updates (id serial not null primary key,
250 owner_uid integer not null references ttrss_users(id) ON DELETE CASCADE,
251 feed_id integer default null references ttrss_feeds(id) ON DELETE CASCADE,
252 entered timestamp not null default NOW());
253
254 create table ttrss_sessions (id varchar(250) unique not null primary key,
255 data text,
256 expire integer not null);
257
258 create index ttrss_sessions_expire_index on ttrss_sessions(expire);
259
260 commit;