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