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