1 /* local and remote users have profiles */
3 create sequence profile_seq;
5 id bigint default nextval('profile_seq') primary key /* comment 'unique identifier' */,
6 nickname varchar(64) not null /* comment 'nickname or username' */,
7 fullname varchar(255) /* comment 'display name' */,
8 profileurl varchar(255) /* comment 'URL, cached so we dont regenerate' */,
9 homepage varchar(255) /* comment 'identifying URL' */,
10 bio varchar(140) /* comment 'descriptive biography' */,
11 location varchar(255) /* comment 'physical location' */,
12 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
13 modified timestamp /* comment 'date this record was modified' */,
17 create index profile_nickname_idx on profile using btree(nickname);
20 profile_id integer not null /* comment 'foreign key to profile table' */ references profile (id) ,
21 original integer default 0 /* comment 'uploaded by user or generated?' */,
22 width integer not null /* comment 'image width' */,
23 height integer not null /* comment 'image height' */,
24 mediatype varchar(32) not null /* comment 'file type' */,
25 filename varchar(255) null /* comment 'local filename, if local' */,
26 url varchar(255) unique /* comment 'avatar location' */,
27 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
28 modified timestamp /* comment 'date this record was modified' */,
30 primary key(profile_id, width, height)
32 create index avatar_profile_id_idx on avatar using btree(profile_id);
34 create sequence sms_carrier_seq;
35 create table sms_carrier (
36 id bigint default nextval('sms_carrier_seq') primary key /* comment 'primary key for SMS carrier' */,
37 name varchar(64) unique /* comment 'name of the carrier' */,
38 email_pattern varchar(255) not null /* comment 'sprintf pattern for making an email address from a phone number' */,
39 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
40 modified timestamp /* comment 'date this record was modified ' */
43 create sequence design_seq;
45 id bigint default nextval('design_seq') /* comment 'design ID'*/,
46 backgroundcolor integer /* comment 'main background color'*/ ,
47 contentcolor integer /*comment 'content area background color'*/ ,
48 sidebarcolor integer /*comment 'sidebar background color'*/ ,
49 textcolor integer /*comment 'text color'*/ ,
50 linkcolor integer /*comment 'link color'*/,
51 backgroundimage varchar(255) /*comment 'background image, if any'*/,
52 disposition int default 1 /*comment 'bit 1 = hide background image, bit 2 = display background image, bit 4 = tile background image'*/,
59 id integer primary key /* comment 'foreign key to profile table' */ references profile (id) ,
60 nickname varchar(64) unique /* comment 'nickname or username, duped in profile' */,
61 password varchar(255) /* comment 'salted password, can be null for OpenID users' */,
62 email varchar(255) unique /* comment 'email address for password recovery etc.' */,
63 incomingemail varchar(255) unique /* comment 'email address for post-by-email' */,
64 emailnotifysub integer default 1 /* comment 'Notify by email of subscriptions' */,
65 emailnotifyfav integer default 1 /* comment 'Notify by email of favorites' */,
66 emailnotifynudge integer default 1 /* comment 'Notify by email of nudges' */,
67 emailnotifymsg integer default 1 /* comment 'Notify by email of direct messages' */,
68 emailnotifyattn integer default 1 /* command 'Notify by email of @-replies' */,
69 emailmicroid integer default 1 /* comment 'whether to publish email microid' */,
70 language varchar(50) /* comment 'preferred language' */,
71 timezone varchar(50) /* comment 'timezone' */,
72 emailpost integer default 1 /* comment 'Post by email' */,
73 jabber varchar(255) unique /* comment 'jabber ID for notices' */,
74 jabbernotify integer default 0 /* comment 'whether to send notices to jabber' */,
75 jabberreplies integer default 0 /* comment 'whether to send notices to jabber on replies' */,
76 jabbermicroid integer default 1 /* comment 'whether to publish xmpp microid' */,
77 updatefrompresence integer default 0 /* comment 'whether to record updates from Jabber presence notices' */,
78 sms varchar(64) unique /* comment 'sms phone number' */,
79 carrier integer /* comment 'foreign key to sms_carrier' */ references sms_carrier (id) ,
80 smsnotify integer default 0 /* comment 'whether to send notices to SMS' */,
81 smsreplies integer default 0 /* comment 'whether to send notices to SMS on replies' */,
82 smsemail varchar(255) /* comment 'built from sms and carrier' */,
83 uri varchar(255) unique /* comment 'universally unique identifier, usually a tag URI' */,
84 autosubscribe integer default 0 /* comment 'automatically subscribe to users who subscribe to us' */,
85 urlshorteningservice varchar(50) default 'ur1.ca' /* comment 'service to use for auto-shortening URLs' */,
86 inboxed integer default 0 /* comment 'has an inbox been created for this user?' */,
87 design_id integer /* comment 'id of a design' */references design(id),
88 viewdesigns integer default 1 /* comment 'whether to view user-provided designs'*/,
89 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
90 modified timestamp /* comment 'date this record was modified' */
93 create index user_smsemail_idx on "user" using btree(smsemail);
97 create table remote_profile (
98 id integer primary key /* comment 'foreign key to profile table' */ references profile (id) ,
99 uri varchar(255) unique /* comment 'universally unique identifier, usually a tag URI' */,
100 postnoticeurl varchar(255) /* comment 'URL we use for posting notices' */,
101 updateprofileurl varchar(255) /* comment 'URL we use for updates to this profile' */,
102 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
103 modified timestamp /* comment 'date this record was modified' */
106 create table subscription (
107 subscriber integer not null /* comment 'profile listening' */,
108 subscribed integer not null /* comment 'profile being listened to' */,
109 jabber integer default 1 /* comment 'deliver jabber messages' */,
110 sms integer default 1 /* comment 'deliver sms messages' */,
111 token varchar(255) /* comment 'authorization token' */,
112 secret varchar(255) /* comment 'token secret' */,
113 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
114 modified timestamp /* comment 'date this record was modified' */,
116 primary key (subscriber, subscribed)
118 create index subscription_subscriber_idx on subscription using btree(subscriber,created);
119 create index subscription_subscribed_idx on subscription using btree(subscribed,created);
121 create sequence notice_seq;
122 create table notice (
124 id bigint default nextval('notice_seq') primary key /* comment 'unique identifier' */,
125 profile_id integer not null /* comment 'who made the update' */ references profile (id) ,
126 uri varchar(255) unique /* comment 'universally unique identifier, usually a tag URI' */,
127 content varchar(140) /* comment 'update content' */,
128 rendered text /* comment 'HTML version of the content' */,
129 url varchar(255) /* comment 'URL of any attachment (image, video, bookmark, whatever)' */,
130 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
131 modified timestamp /* comment 'date this record was modified' */,
132 reply_to integer /* comment 'notice replied to (usually a guess)' */ references notice (id) ,
133 is_local integer default 0 /* comment 'notice was generated by a user' */,
134 source varchar(32) /* comment 'source of comment, like "web", "im", or "clientname"' */,
135 conversation integer /*id of root notice in this conversation' */ references notice (id)
138 /* FULLTEXT(content) */
140 create index notice_profile_id_idx on notice using btree(profile_id);
141 create index notice_created_idx on notice using btree(created);
143 create table notice_source (
144 code varchar(32) primary key not null /* comment 'source code' */,
145 name varchar(255) not null /* comment 'name of the source' */,
146 url varchar(255) not null /* comment 'url to link to' */,
147 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
148 modified timestamp /* comment 'date this record was modified' */
153 notice_id integer not null /* comment 'notice that is the reply' */ references notice (id) ,
154 profile_id integer not null /* comment 'profile replied to' */ references profile (id) ,
155 modified timestamp /* comment 'date this record was modified' */,
156 replied_id integer /* comment 'notice replied to (not used, see notice.reply_to)' */,
158 primary key (notice_id, profile_id)
161 create index reply_notice_id_idx on reply using btree(notice_id);
162 create index reply_profile_id_idx on reply using btree(profile_id);
163 create index reply_replied_id_idx on reply using btree(replied_id);
167 notice_id integer not null /* comment 'notice that is the favorite' */ references notice (id),
168 user_id integer not null /* comment 'user who likes this notice' */ references "user" (id) ,
169 modified timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was modified' */,
170 primary key (notice_id, user_id)
173 create index fave_notice_id_idx on fave using btree(notice_id);
174 create index fave_user_id_idx on fave using btree(user_id,modified);
175 create index fave_modified_idx on fave using btree(modified);
177 /* tables for OAuth */
179 create table consumer (
180 consumer_key varchar(255) primary key /* comment 'unique identifier, root URL' */,
181 seed char(32) not null /* comment 'seed for new tokens by this consumer' */,
183 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
184 modified timestamp /* comment 'date this record was modified' */
188 consumer_key varchar(255) not null /* comment 'unique identifier, root URL' */ references consumer (consumer_key),
189 tok char(32) not null /* comment 'identifying value' */,
190 secret char(32) not null /* comment 'secret value' */,
191 type integer not null default 0 /* comment 'request or access' */,
192 state integer default 0 /* comment 'for requests 0 = initial, 1 = authorized, 2 = used' */,
194 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
195 modified timestamp /* comment 'date this record was modified' */,
197 primary key (consumer_key, tok)
201 consumer_key varchar(255) not null /* comment 'unique identifier, root URL' */,
202 tok char(32) /* comment 'buggy old value, ignored' */,
203 nonce char(32) null /* comment 'buggy old value, ignored */,
204 ts integer not null /* comment 'timestamp sent' values are epoch, and only used internally */,
206 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
207 modified timestamp /* comment 'date this record was modified' */,
209 primary key (consumer_key, ts, nonce)
212 /* One-to-many relationship of user to openid_url */
214 create table user_openid (
215 canonical varchar(255) primary key /* comment 'Canonical true URL' */,
216 display varchar(255) not null unique /* comment 'URL for viewing, may be different from canonical' */,
217 user_id integer not null /* comment 'user owning this URL' */ references "user" (id) ,
218 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
219 modified timestamp /* comment 'date this record was modified' */
222 create index user_openid_user_id_idx on user_openid using btree(user_id);
224 /* These are used by JanRain OpenID library */
226 create table oid_associations (
227 server_url varchar(2047),
232 assoc_type varchar(64),
233 primary key (server_url, handle)
236 create table oid_nonces (
237 server_url varchar(2047),
240 unique (server_url, "timestamp", salt)
243 create table confirm_address (
244 code varchar(32) not null primary key /* comment 'good random code' */,
245 user_id integer not null /* comment 'user who requested confirmation' */ references "user" (id),
246 address varchar(255) not null /* comment 'address (email, Jabber, SMS, etc.)' */,
247 address_extra varchar(255) not null default '' /* comment 'carrier ID, for SMS' */,
248 address_type varchar(8) not null /* comment 'address type ("email", "jabber", "sms")' */,
249 claimed timestamp /* comment 'date this was claimed for queueing' */,
250 sent timestamp /* comment 'date this was sent for queueing' */,
251 modified timestamp /* comment 'date this record was modified' */
254 create table remember_me (
255 code varchar(32) not null primary key /* comment 'good random code' */,
256 user_id integer not null /* comment 'user who is logged in' */ references "user" (id),
257 modified timestamp /* comment 'date this record was modified' */
260 create table queue_item (
262 notice_id integer not null /* comment 'notice queued' */ references notice (id) ,
263 transport varchar(8) not null /* comment 'queue for what? "email", "jabber", "sms", "irc", ...' */,
264 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
265 claimed timestamp /* comment 'date this item was claimed' */,
267 primary key (notice_id, transport)
270 create index queue_item_created_idx on queue_item using btree(created);
273 create table notice_tag (
274 tag varchar( 64 ) not null /* comment 'hash tag associated with this notice' */,
275 notice_id integer not null /* comment 'notice tagged' */ references notice (id) ,
276 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
278 primary key (tag, notice_id)
280 create index notice_tag_created_idx on notice_tag using btree(created);
282 /* Synching with foreign services */
284 create table foreign_service (
285 id int not null primary key /* comment 'numeric key for service' */,
286 name varchar(32) not null unique /* comment 'name of the service' */,
287 description varchar(255) /* comment 'description' */,
288 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
289 modified timestamp /* comment 'date this record was modified' */
292 create table foreign_user (
293 id int not null unique /* comment 'unique numeric key on foreign service' */,
294 service int not null /* comment 'foreign key to service' */ references foreign_service(id) ,
295 uri varchar(255) not null unique /* comment 'identifying URI' */,
296 nickname varchar(255) /* comment 'nickname on foreign service' */,
297 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
298 modified timestamp /* comment 'date this record was modified' */,
300 primary key (id, service)
303 create table foreign_link (
304 user_id int /* comment 'link to user on this system, if exists' */ references "user" (id),
305 foreign_id int /* comment 'link' */ references foreign_user (id),
306 service int not null /* comment 'foreign key to service' */ references foreign_service (id),
307 credentials varchar(255) /* comment 'authc credentials, typically a password' */,
308 noticesync int not null default 1 /* comment 'notice synchronisation, bit 1 = sync outgoing, bit 2 = sync incoming, bit 3 = filter local replies' */,
309 friendsync int not null default 2 /* comment 'friend synchronisation, bit 1 = sync outgoing, bit 2 = sync incoming */,
310 profilesync int not null default 1 /* comment 'profile synchronization, bit 1 = sync outgoing, bit 2 = sync incoming' */,
311 last_noticesync timestamp default null /* comment 'last time notices were imported' */,
312 last_friendsync timestamp default null /* comment 'last time friends were imported' */,
313 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
314 modified timestamp /* comment 'date this record was modified' */,
316 primary key (user_id,foreign_id,service)
318 create index foreign_user_user_id_idx on foreign_link using btree(user_id);
320 create table foreign_subscription (
321 service int not null /* comment 'service where relationship happens' */ references foreign_service(id) ,
322 subscriber int not null /* comment 'subscriber on foreign service' */ ,
323 subscribed int not null /* comment 'subscribed user' */ ,
324 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
326 primary key (service, subscriber, subscribed)
328 create index foreign_subscription_subscriber_idx on foreign_subscription using btree(subscriber);
329 create index foreign_subscription_subscribed_idx on foreign_subscription using btree(subscribed);
331 create table invitation (
332 code varchar(32) not null primary key /* comment 'random code for an invitation' */,
333 user_id int not null /* comment 'who sent the invitation' */ references "user" (id),
334 address varchar(255) not null /* comment 'invitation sent to' */,
335 address_type varchar(8) not null /* comment 'address type ("email", "jabber", "sms") '*/,
336 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */
339 create index invitation_address_idx on invitation using btree(address,address_type);
340 create index invitation_user_id_idx on invitation using btree(user_id);
342 create sequence message_seq;
343 create table message (
345 id bigint default nextval('message_seq') primary key /* comment 'unique identifier' */,
346 uri varchar(255) unique /* comment 'universally unique identifier' */,
347 from_profile integer not null /* comment 'who the message is from' */ references profile (id),
348 to_profile integer not null /* comment 'who the message is to' */ references profile (id),
349 content varchar(140) /* comment 'message content' */,
350 rendered text /* comment 'HTML version of the content' */,
351 url varchar(255) /* comment 'URL of any attachment (image, video, bookmark, whatever)' */,
352 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
353 modified timestamp /* comment 'date this record was modified' */,
354 source varchar(32) /* comment 'source of comment, like "web", "im", or "clientname"' */
357 create index message_from_idx on message using btree(from_profile);
358 create index message_to_idx on message using btree(to_profile);
359 create index message_created_idx on message using btree(created);
361 create table notice_inbox (
363 user_id integer not null /* comment 'user receiving the message' */ references "user" (id),
364 notice_id integer not null /* comment 'notice received' */ references notice (id),
365 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date the notice was created' */,
366 source integer default 1 /* comment 'reason it is in the inbox: 1=subscription' */,
368 primary key (user_id, notice_id)
370 create index notice_inbox_notice_id_idx on notice_inbox using btree(notice_id);
372 create table profile_tag (
373 tagger integer not null /* comment 'user making the tag' */ references "user" (id),
374 tagged integer not null /* comment 'profile tagged' */ references profile (id),
375 tag varchar(64) not null /* comment 'hash tag associated with this notice' */,
376 modified timestamp /* comment 'date the tag was added' */,
378 primary key (tagger, tagged, tag)
380 create index profile_tag_modified_idx on profile_tag using btree(modified);
381 create index profile_tag_tagger_tag_idx on profile_tag using btree(tagger,tag);
383 create table profile_block (
385 blocker integer not null /* comment 'user making the block' */ references "user" (id),
386 blocked integer not null /* comment 'profile that is blocked' */ references profile (id),
387 modified timestamp /* comment 'date of blocking' */,
389 primary key (blocker, blocked)
393 create sequence user_group_seq;
394 create table user_group (
396 id bigint default nextval('user_group_seq') primary key /* comment 'unique identifier' */,
398 nickname varchar(64) unique /* comment 'nickname for addressing' */,
399 fullname varchar(255) /* comment 'display name' */,
400 homepage varchar(255) /* comment 'URL, cached so we dont regenerate' */,
401 description varchar(140) /* comment 'descriptive biography' */,
402 location varchar(255) /* comment 'related physical location, if any' */,
404 original_logo varchar(255) /* comment 'original size logo' */,
405 homepage_logo varchar(255) /* comment 'homepage (profile) size logo' */,
406 stream_logo varchar(255) /* comment 'stream-sized logo' */,
407 mini_logo varchar(255) /* comment 'mini logo' */,
408 design_id integer /*comment 'id of a design' */ references design(id),
411 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
412 modified timestamp /* comment 'date this record was modified' */
415 create index user_group_nickname_idx on user_group using btree(nickname);
417 create table group_member (
419 group_id integer not null /* comment 'foreign key to user_group' */ references user_group (id),
420 profile_id integer not null /* comment 'foreign key to profile table' */ references profile (id),
421 is_admin integer default 0 /* comment 'is this user an admin?' */,
423 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
424 modified timestamp /* comment 'date this record was modified' */,
426 primary key (group_id, profile_id)
429 create table related_group (
431 group_id integer not null /* comment 'foreign key to user_group' */ references user_group (id) ,
432 related_group_id integer not null /* comment 'foreign key to user_group' */ references user_group (id),
434 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
436 primary key (group_id, related_group_id)
440 create table group_inbox (
441 group_id integer not null /* comment 'group receiving the message' references user_group (id) */,
442 notice_id integer not null /* comment 'notice received' references notice (id) */,
443 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date the notice was created' */,
444 primary key (group_id, notice_id)
446 create index group_inbox_created_idx on group_inbox using btree(created);
449 /*attachments and URLs stuff */
450 create sequence file_seq;
452 id bigint default nextval('file_seq') primary key /* comment 'unique identifier' */,
453 url varchar(255) unique,
454 mimetype varchar(50),
459 filename text /* comment 'if a local file, name of the file' */,
460 modified timestamp default CURRENT_TIMESTAMP /* comment 'date this record was modified'*/
463 create sequence file_oembed_seq;
464 create table file_oembed (
465 file_id bigint default nextval('file_oembed_seq') primary key /* comment 'unique identifier' */,
468 mimetype varchar(50),
469 provider varchar(50),
470 provider_url varchar(255),
475 author_name varchar(50),
476 author_url varchar(255),
480 create sequence file_redirection_seq;
481 create table file_redirection (
482 url varchar(255) primary key,
484 redirections integer,
488 create sequence file_thumbnail_seq;
489 create table file_thumbnail (
490 file_id bigint primary key,
491 url varchar(255) unique,
496 create sequence file_to_post_seq;
497 create table file_to_post (
501 primary key (file_id, post_id)
504 create table group_block (
505 group_id integer not null /* comment 'group profile is blocked from' */ references user_group (id),
506 blocked integer not null /* comment 'profile that is blocked' */references profile (id),
507 blocker integer not null /* comment 'user making the block'*/ references "user" (id),
508 modified timestamp /* comment 'date of blocking'*/ ,
510 primary key (group_id, blocked)
513 create table group_alias (
515 alias varchar(64) /* comment 'additional nickname for the group'*/ ,
516 group_id integer not null /* comment 'group profile is blocked from'*/ references user_group (id),
517 modified timestamp /* comment 'date alias was created'*/,
521 create index group_alias_group_id_idx on group_alias (group_id);
523 create table session (
525 id varchar(32) primary key /* comment 'session ID'*/,
526 session_data text /* comment 'session data'*/,
527 created timestamp not null DEFAULT CURRENT_TIMESTAMP /* comment 'date this record was created'*/,
528 modified integer DEFAULT extract(epoch from CURRENT_TIMESTAMP) /* comment 'date this record was modified'*/
531 create index session_modified_idx on session (modified);
533 create table deleted_notice (
535 id integer primary key /* comment 'identity of notice'*/ ,
536 profile_id integer /* not null comment 'author of the notice'*/,
537 uri varchar(255) unique /* comment 'universally unique identifier, usually a tag URI'*/,
538 created timestamp not null /* comment 'date the notice record was created'*/ ,
539 deleted timestamp not null DEFAULT CURRENT_TIMESTAMP /* comment 'date the notice record was created'*/
542 CREATE index deleted_notice_profile_id_idx on deleted_notice (profile_id);
545 /* Textsearch stuff */
547 create index textsearch_idx on profile using gist(textsearch);
548 create index noticecontent_idx on notice using gist(to_tsvector('english',content));
549 create trigger textsearchupdate before insert or update on profile for each row
550 execute procedure tsvector_update_trigger(textsearch, 'pg_catalog.english', nickname, fullname, location, bio, homepage);
553 create table config (
555 section varchar(32) /* comment 'configuration section'*/,
556 setting varchar(32) /* comment 'configuration setting'*/,
557 value varchar(255) /* comment 'configuration value'*/,
559 primary key (section, setting)
563 create table user_role (
565 user_id integer not null /* comment 'user having the role'*/ references "user" (id),
566 role varchar(32) not null /* comment 'string representing the role'*/,
567 created timestamp /* not null comment 'date the role was granted'*/,
569 primary key (user_id, role)
573 create table login_token (
574 user_id integer not null /* comment 'user owning this token'*/ references user (id),
575 token char(32) not null /* comment 'token useable for logging in'*/,
576 created timestamp not null DEFAULT CURRENT_TIMESTAMP /* comment 'date this record was created'*/,
577 modified timestamp /* comment 'date this record was modified'*/,
579 constraint primary key (user_id)