1 /* local and remote users have profiles */
2 create sequence profile_seq;
4 id bigint default nextval('profile_seq') primary key /* comment 'unique identifier' */,
5 nickname varchar(64) not null /* comment 'nickname or username' */,
6 fullname varchar(255) /* comment 'display name' */,
7 profileurl varchar(255) /* comment 'URL, cached so we dont regenerate' */,
8 homepage varchar(255) /* comment 'identifying URL' */,
9 bio varchar(140) /* comment 'descriptive biography' */,
10 location varchar(255) /* comment 'physical location' */,
11 lat decimal(10,7) /* comment 'latitude'*/ ,
12 lon decimal(10,7) /* comment 'longitude'*/ ,
13 location_id integer /* comment 'location id if possible'*/ ,
14 location_ns integer /* comment 'namespace for location'*/ ,
15 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
16 modified timestamp /* comment 'date this record was modified' */,
20 create index profile_nickname_idx on profile using btree(nickname);
23 profile_id integer not null /* comment 'foreign key to profile table' */ references profile (id) ,
24 original integer default 0 /* comment 'uploaded by user or generated?' */,
25 width integer not null /* comment 'image width' */,
26 height integer not null /* comment 'image height' */,
27 mediatype varchar(32) not null /* comment 'file type' */,
28 filename varchar(255) null /* comment 'local filename, if local' */,
29 url varchar(255) unique /* comment 'avatar location' */,
30 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
31 modified timestamp /* comment 'date this record was modified' */,
33 primary key(profile_id, width, height)
35 create index avatar_profile_id_idx on avatar using btree(profile_id);
37 create sequence sms_carrier_seq;
38 create table sms_carrier (
39 id bigint default nextval('sms_carrier_seq') primary key /* comment 'primary key for SMS carrier' */,
40 name varchar(64) unique /* comment 'name of the carrier' */,
41 email_pattern varchar(255) not null /* comment 'sprintf pattern for making an email address from a phone number' */,
42 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
43 modified timestamp /* comment 'date this record was modified ' */
46 create sequence design_seq;
48 id bigint default nextval('design_seq') /* comment 'design ID'*/,
49 backgroundcolor integer /* comment 'main background color'*/ ,
50 contentcolor integer /*comment 'content area background color'*/ ,
51 sidebarcolor integer /*comment 'sidebar background color'*/ ,
52 textcolor integer /*comment 'text color'*/ ,
53 linkcolor integer /*comment 'link color'*/,
54 backgroundimage varchar(255) /*comment 'background image, if any'*/,
55 disposition int default 1 /*comment 'bit 1 = hide background image, bit 2 = display background image, bit 4 = tile background image'*/,
62 id integer primary key /* comment 'foreign key to profile table' */ references profile (id) ,
63 nickname varchar(64) unique /* comment 'nickname or username, duped in profile' */,
64 password varchar(255) /* comment 'salted password, can be null for OpenID users' */,
65 email varchar(255) unique /* comment 'email address for password recovery etc.' */,
66 incomingemail varchar(255) unique /* comment 'email address for post-by-email' */,
67 emailnotifysub integer default 1 /* comment 'Notify by email of subscriptions' */,
68 emailnotifyfav integer default 1 /* comment 'Notify by email of favorites' */,
69 emailnotifynudge integer default 1 /* comment 'Notify by email of nudges' */,
70 emailnotifymsg integer default 1 /* comment 'Notify by email of direct messages' */,
71 emailnotifyattn integer default 1 /* command 'Notify by email of @-replies' */,
72 emailmicroid integer default 1 /* comment 'whether to publish email microid' */,
73 language varchar(50) /* comment 'preferred language' */,
74 timezone varchar(50) /* comment 'timezone' */,
75 emailpost integer default 1 /* comment 'Post by email' */,
76 jabber varchar(255) unique /* comment 'jabber ID for notices' */,
77 jabbernotify integer default 0 /* comment 'whether to send notices to jabber' */,
78 jabberreplies integer default 0 /* comment 'whether to send notices to jabber on replies' */,
79 jabbermicroid integer default 1 /* comment 'whether to publish xmpp microid' */,
80 updatefrompresence integer default 0 /* comment 'whether to record updates from Jabber presence notices' */,
81 sms varchar(64) unique /* comment 'sms phone number' */,
82 carrier integer /* comment 'foreign key to sms_carrier' */ references sms_carrier (id) ,
83 smsnotify integer default 0 /* comment 'whether to send notices to SMS' */,
84 smsreplies integer default 0 /* comment 'whether to send notices to SMS on replies' */,
85 smsemail varchar(255) /* comment 'built from sms and carrier' */,
86 uri varchar(255) unique /* comment 'universally unique identifier, usually a tag URI' */,
87 autosubscribe integer default 0 /* comment 'automatically subscribe to users who subscribe to us' */,
88 urlshorteningservice varchar(50) default 'ur1.ca' /* comment 'service to use for auto-shortening URLs' */,
89 inboxed integer default 0 /* comment 'has an inbox been created for this user?' */,
90 design_id integer /* comment 'id of a design' */references design(id),
91 viewdesigns integer default 1 /* comment 'whether to view user-provided designs'*/,
92 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
93 modified timestamp /* comment 'date this record was modified' */
96 create index user_smsemail_idx on "user" using btree(smsemail);
100 create table remote_profile (
101 id integer primary key /* comment 'foreign key to profile table' */ references profile (id) ,
102 uri varchar(255) unique /* comment 'universally unique identifier, usually a tag URI' */,
103 postnoticeurl varchar(255) /* comment 'URL we use for posting notices' */,
104 updateprofileurl varchar(255) /* comment 'URL we use for updates to this profile' */,
105 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
106 modified timestamp /* comment 'date this record was modified' */
109 create table subscription (
110 subscriber integer not null /* comment 'profile listening' */,
111 subscribed integer not null /* comment 'profile being listened to' */,
112 jabber integer default 1 /* comment 'deliver jabber messages' */,
113 sms integer default 1 /* comment 'deliver sms messages' */,
114 token varchar(255) /* comment 'authorization token' */,
115 secret varchar(255) /* comment 'token secret' */,
116 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
117 modified timestamp /* comment 'date this record was modified' */,
119 primary key (subscriber, subscribed)
121 create index subscription_subscriber_idx on subscription using btree(subscriber,created);
122 create index subscription_subscribed_idx on subscription using btree(subscribed,created);
124 create sequence notice_seq;
125 create table notice (
127 id bigint default nextval('notice_seq') primary key /* comment 'unique identifier' */,
128 profile_id integer not null /* comment 'who made the update' */ references profile (id) ,
129 uri varchar(255) unique /* comment 'universally unique identifier, usually a tag URI' */,
130 content varchar(140) /* comment 'update content' */,
131 rendered text /* comment 'HTML version of the content' */,
132 url varchar(255) /* comment 'URL of any attachment (image, video, bookmark, whatever)' */,
133 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
134 modified timestamp /* comment 'date this record was modified' */,
135 reply_to integer /* comment 'notice replied to (usually a guess)' */ references notice (id) ,
136 is_local integer default 0 /* comment 'notice was generated by a user' */,
137 source varchar(32) /* comment 'source of comment, like "web", "im", or "clientname"' */,
138 conversation integer /*id of root notice in this conversation' */ references notice (id),
139 lat decimal(10,7) /* comment 'latitude'*/ ,
140 lon decimal(10,7) /* comment 'longitude'*/ ,
141 location_id integer /* comment 'location id if possible'*/ ,
142 location_ns integer /* comment 'namespace for location'*/ ,
143 repeat_of integer /* comment 'notice this is a repeat of' */ references notice (id)
145 /* FULLTEXT(content) */
148 create index notice_profile_id_idx on notice using btree(profile_id,created,id);
149 create index notice_created_idx on notice using btree(created);
151 create table notice_source (
152 code varchar(32) primary key not null /* comment 'source code' */,
153 name varchar(255) not null /* comment 'name of the source' */,
154 url varchar(255) not null /* comment 'url to link to' */,
155 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
156 modified timestamp /* comment 'date this record was modified' */
161 notice_id integer not null /* comment 'notice that is the reply' */ references notice (id) ,
162 profile_id integer not null /* comment 'profile replied to' */ references profile (id) ,
163 modified timestamp /* comment 'date this record was modified' */,
164 replied_id integer /* comment 'notice replied to (not used, see notice.reply_to)' */,
166 primary key (notice_id, profile_id)
169 create index reply_notice_id_idx on reply using btree(notice_id);
170 create index reply_profile_id_idx on reply using btree(profile_id);
171 create index reply_replied_id_idx on reply using btree(replied_id);
175 notice_id integer not null /* comment 'notice that is the favorite' */ references notice (id),
176 user_id integer not null /* comment 'user who likes this notice' */ references "user" (id) ,
177 modified timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was modified' */,
178 primary key (notice_id, user_id)
181 create index fave_notice_id_idx on fave using btree(notice_id);
182 create index fave_user_id_idx on fave using btree(user_id,modified);
183 create index fave_modified_idx on fave using btree(modified);
185 /* tables for OAuth */
187 create table consumer (
188 consumer_key varchar(255) primary key /* comment 'unique identifier, root URL' */,
189 consumer_secret varchar(255) not null /* comment 'secret value', */,
190 seed char(32) not null /* comment 'seed for new tokens by this consumer' */,
192 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
193 modified timestamp /* comment 'date this record was modified' */
197 consumer_key varchar(255) not null /* comment 'unique identifier, root URL' */ references consumer (consumer_key),
198 tok char(32) not null /* comment 'identifying value' */,
199 secret char(32) not null /* comment 'secret value' */,
200 type integer not null default 0 /* comment 'request or access' */,
201 state integer default 0 /* comment 'for requests 0 = initial, 1 = authorized, 2 = used' */,
203 verifier varchar(255) /*comment 'verifier string for OAuth 1.0a'*/,
204 verified_callback varchar(255) /*comment 'verified callback URL for OAuth 1.0a'*/,
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, tok)
213 consumer_key varchar(255) not null /* comment 'unique identifier, root URL' */,
214 tok char(32) /* comment 'buggy old value, ignored' */,
215 nonce char(32) null /* comment 'buggy old value, ignored */,
216 ts integer not null /* comment 'timestamp sent' values are epoch, and only used internally */,
218 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
219 modified timestamp /* comment 'date this record was modified' */,
221 primary key (consumer_key, ts, nonce)
224 create sequence oauth_application_seq;
225 create table oauth_application (
226 id bigint default nextval('oauth_application_seq') primary key /* comment 'unique identifier' */,
227 owner integer not null /* comment 'owner of the application' */ references profile (id),
228 consumer_key varchar(255) not null /* comment 'application consumer key' */ references consumer (consumer_key),
229 name varchar(255) unique not null /* comment 'name of the application' */,
230 description varchar(255) /* comment 'description of the application' */,
231 icon varchar(255) not null /* comment 'application icon' */,
232 source_url varchar(255) /* comment 'application homepage - used for source link' */,
233 organization varchar(255) /* comment 'name of the organization running the application' */,
234 homepage varchar(255) /* comment 'homepage for the organization' */,
235 callback_url varchar(255) /* comment 'url to redirect to after authentication' */,
236 "type" integer default 0 /* comment 'type of app, 1 = browser, 2 = desktop' */,
237 access_type integer default 0 /* comment 'default access type, bit 1 = read, bit 2 = write' */,
238 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
239 modified timestamp /* comment 'date this record was modified' */
242 create table oauth_application_user (
243 profile_id integer not null /* 'user of the application' */ references profile (id),
244 application_id integer not null /* 'id of the application' */ references oauth_application (id),
245 access_type integer default 0 /* 'access type, bit 1 = read, bit 2 = write' */,
246 token varchar(255) /* 'request or access token' */,
247 created timestamp not null default CURRENT_TIMESTAMP /* 'date this record was created' */,
248 modified timestamp /* 'date this record was modified' */,
249 primary key (profile_id, application_id)
252 /* These are used by JanRain OpenID library */
254 create table oid_associations (
255 server_url varchar(2047),
260 assoc_type varchar(64),
261 primary key (server_url, handle)
264 create table oid_nonces (
265 server_url varchar(2047),
268 unique (server_url, "timestamp", salt)
271 create table confirm_address (
272 code varchar(32) not null primary key /* comment 'good random code' */,
273 user_id integer not null /* comment 'user who requested confirmation' */ references "user" (id),
274 address varchar(255) not null /* comment 'address (email, Jabber, SMS, etc.)' */,
275 address_extra varchar(255) not null default '' /* comment 'carrier ID, for SMS' */,
276 address_type varchar(8) not null /* comment 'address type ("email", "jabber", "sms")' */,
277 claimed timestamp /* comment 'date this was claimed for queueing' */,
278 sent timestamp default CURRENT_TIMESTAMP /* comment 'date this was sent for queueing' */,
279 modified timestamp /* comment 'date this record was modified' */
282 create table remember_me (
283 code varchar(32) not null primary key /* comment 'good random code' */,
284 user_id integer not null /* comment 'user who is logged in' */ references "user" (id),
285 modified timestamp /* comment 'date this record was modified' */
288 create table queue_item (
289 id serial /* comment 'unique identifier'*/,
290 frame bytea not null /* comment 'data: object reference or opaque string'*/,
291 transport varchar(8) not null /*comment 'queue for what? "email", "jabber", "sms", "irc", ...'*/,
292 created timestamp not null default CURRENT_TIMESTAMP /*comment 'date this record was created'*/,
293 claimed timestamp /*comment 'date this item was claimed'*/,
296 create index queue_item_created_idx on queue_item using btree(created);
299 create table notice_tag (
300 tag varchar( 64 ) not null /* comment 'hash tag associated with this notice' */,
301 notice_id integer not null /* comment 'notice tagged' */ references notice (id) ,
302 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
304 primary key (tag, notice_id)
306 create index notice_tag_created_idx on notice_tag using btree(created);
308 /* Synching with foreign services */
310 create table foreign_service (
311 id int not null primary key /* comment 'numeric key for service' */,
312 name varchar(32) not null unique /* comment 'name of the service' */,
313 description varchar(255) /* comment 'description' */,
314 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
315 modified timestamp /* comment 'date this record was modified' */
318 create table foreign_user (
319 id int not null unique /* comment 'unique numeric key on foreign service' */,
320 service int not null /* comment 'foreign key to service' */ references foreign_service(id) ,
321 uri varchar(255) not null unique /* comment 'identifying URI' */,
322 nickname varchar(255) /* comment 'nickname on foreign service' */,
323 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
324 modified timestamp /* comment 'date this record was modified' */,
326 primary key (id, service)
329 create table foreign_link (
330 user_id int /* comment 'link to user on this system, if exists' */ references "user" (id),
331 foreign_id int /* comment 'link' */ references foreign_user (id),
332 service int not null /* comment 'foreign key to service' */ references foreign_service (id),
333 credentials varchar(255) /* comment 'authc credentials, typically a password' */,
334 noticesync int not null default 1 /* comment 'notice synchronisation, bit 1 = sync outgoing, bit 2 = sync incoming, bit 3 = filter local replies' */,
335 friendsync int not null default 2 /* comment 'friend synchronisation, bit 1 = sync outgoing, bit 2 = sync incoming */,
336 profilesync int not null default 1 /* comment 'profile synchronization, bit 1 = sync outgoing, bit 2 = sync incoming' */,
337 last_noticesync timestamp default null /* comment 'last time notices were imported' */,
338 last_friendsync timestamp default null /* comment 'last time friends were imported' */,
339 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
340 modified timestamp /* comment 'date this record was modified' */,
342 primary key (user_id,foreign_id,service)
344 create index foreign_user_user_id_idx on foreign_link using btree(user_id);
346 create table foreign_subscription (
347 service int not null /* comment 'service where relationship happens' */ references foreign_service(id) ,
348 subscriber int not null /* comment 'subscriber on foreign service' */ ,
349 subscribed int not null /* comment 'subscribed user' */ ,
350 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
352 primary key (service, subscriber, subscribed)
354 create index foreign_subscription_subscriber_idx on foreign_subscription using btree(subscriber);
355 create index foreign_subscription_subscribed_idx on foreign_subscription using btree(subscribed);
357 create table invitation (
358 code varchar(32) not null primary key /* comment 'random code for an invitation' */,
359 user_id int not null /* comment 'who sent the invitation' */ references "user" (id),
360 address varchar(255) not null /* comment 'invitation sent to' */,
361 address_type varchar(8) not null /* comment 'address type ("email", "jabber", "sms") '*/,
362 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */
365 create index invitation_address_idx on invitation using btree(address,address_type);
366 create index invitation_user_id_idx on invitation using btree(user_id);
368 create sequence message_seq;
369 create table message (
371 id bigint default nextval('message_seq') primary key /* comment 'unique identifier' */,
372 uri varchar(255) unique /* comment 'universally unique identifier' */,
373 from_profile integer not null /* comment 'who the message is from' */ references profile (id),
374 to_profile integer not null /* comment 'who the message is to' */ references profile (id),
375 content varchar(140) /* comment 'message content' */,
376 rendered text /* comment 'HTML version of the content' */,
377 url varchar(255) /* comment 'URL of any attachment (image, video, bookmark, whatever)' */,
378 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
379 modified timestamp /* comment 'date this record was modified' */,
380 source varchar(32) /* comment 'source of comment, like "web", "im", or "clientname"' */
383 create index message_from_idx on message using btree(from_profile);
384 create index message_to_idx on message using btree(to_profile);
385 create index message_created_idx on message using btree(created);
387 create table notice_inbox (
389 user_id integer not null /* comment 'user receiving the message' */ references "user" (id),
390 notice_id integer not null /* comment 'notice received' */ references notice (id),
391 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date the notice was created' */,
392 source integer default 1 /* comment 'reason it is in the inbox: 1=subscription' */,
394 primary key (user_id, notice_id)
396 create index notice_inbox_notice_id_idx on notice_inbox using btree(notice_id);
398 create table profile_tag (
399 tagger integer not null /* comment 'user making the tag' */ references "user" (id),
400 tagged integer not null /* comment 'profile tagged' */ references profile (id),
401 tag varchar(64) not null /* comment 'hash tag associated with this notice' */,
402 modified timestamp /* comment 'date the tag was added' */,
404 primary key (tagger, tagged, tag)
406 create index profile_tag_modified_idx on profile_tag using btree(modified);
407 create index profile_tag_tagger_tag_idx on profile_tag using btree(tagger,tag);
409 create table profile_block (
411 blocker integer not null /* comment 'user making the block' */ references "user" (id),
412 blocked integer not null /* comment 'profile that is blocked' */ references profile (id),
413 modified timestamp /* comment 'date of blocking' */,
415 primary key (blocker, blocked)
419 create sequence user_group_seq;
420 create table user_group (
422 id bigint default nextval('user_group_seq') primary key /* comment 'unique identifier' */,
424 nickname varchar(64) unique /* comment 'nickname for addressing' */,
425 fullname varchar(255) /* comment 'display name' */,
426 homepage varchar(255) /* comment 'URL, cached so we dont regenerate' */,
427 description varchar(140) /* comment 'descriptive biography' */,
428 location varchar(255) /* comment 'related physical location, if any' */,
430 original_logo varchar(255) /* comment 'original size logo' */,
431 homepage_logo varchar(255) /* comment 'homepage (profile) size logo' */,
432 stream_logo varchar(255) /* comment 'stream-sized logo' */,
433 mini_logo varchar(255) /* comment 'mini logo' */,
434 design_id integer /*comment 'id of a design' */ references design(id),
436 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
437 modified timestamp /* comment 'date this record was modified' */
440 create index user_group_nickname_idx on user_group using btree(nickname);
442 create table group_member (
444 group_id integer not null /* comment 'foreign key to user_group' */ references user_group (id),
445 profile_id integer not null /* comment 'foreign key to profile table' */ references profile (id),
446 is_admin integer default 0 /* comment 'is this user an admin?' */,
448 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
449 modified timestamp /* comment 'date this record was modified' */,
451 primary key (group_id, profile_id)
454 create table related_group (
456 group_id integer not null /* comment 'foreign key to user_group' */ references user_group (id) ,
457 related_group_id integer not null /* comment 'foreign key to user_group' */ references user_group (id),
459 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date this record was created' */,
461 primary key (group_id, related_group_id)
465 create table group_inbox (
466 group_id integer not null /* comment 'group receiving the message' references user_group (id) */,
467 notice_id integer not null /* comment 'notice received' references notice (id) */,
468 created timestamp not null default CURRENT_TIMESTAMP /* comment 'date the notice was created' */,
469 primary key (group_id, notice_id)
471 create index group_inbox_created_idx on group_inbox using btree(created);
473 /*attachments and URLs stuff */
474 create sequence file_seq;
476 id bigint default nextval('file_seq') primary key /* comment 'unique identifier' */,
477 url varchar(255) unique,
478 mimetype varchar(50),
483 filename text /* comment 'if a local file, name of the file' */,
484 modified timestamp default CURRENT_TIMESTAMP /* comment 'date this record was modified'*/
487 create sequence file_oembed_seq;
488 create table file_oembed (
489 file_id bigint default nextval('file_oembed_seq') primary key /* comment 'unique identifier' */,
492 mimetype varchar(50),
493 provider varchar(50),
494 provider_url varchar(255),
499 author_name varchar(50),
500 author_url varchar(255),
504 create sequence file_redirection_seq;
505 create table file_redirection (
506 url varchar(255) primary key,
508 redirections integer,
512 create sequence file_thumbnail_seq;
513 create table file_thumbnail (
514 file_id bigint primary key,
515 url varchar(255) unique,
520 create sequence file_to_post_seq;
521 create table file_to_post (
525 primary key (file_id, post_id)
528 create table group_block (
529 group_id integer not null /* comment 'group profile is blocked from' */ references user_group (id),
530 blocked integer not null /* comment 'profile that is blocked' */references profile (id),
531 blocker integer not null /* comment 'user making the block'*/ references "user" (id),
532 modified timestamp /* comment 'date of blocking'*/ ,
534 primary key (group_id, blocked)
537 create table group_alias (
539 alias varchar(64) /* comment 'additional nickname for the group'*/ ,
540 group_id integer not null /* comment 'group profile is blocked from'*/ references user_group (id),
541 modified timestamp /* comment 'date alias was created'*/,
545 create index group_alias_group_id_idx on group_alias (group_id);
547 create table session (
549 id varchar(32) primary key /* comment 'session ID'*/,
550 session_data text /* comment 'session data'*/,
551 created timestamp not null DEFAULT CURRENT_TIMESTAMP /* comment 'date this record was created'*/,
552 modified integer DEFAULT extract(epoch from CURRENT_TIMESTAMP) /* comment 'date this record was modified'*/
555 create index session_modified_idx on session (modified);
557 create table deleted_notice (
559 id integer primary key /* comment 'identity of notice'*/ ,
560 profile_id integer /* not null comment 'author of the notice'*/,
561 uri varchar(255) unique /* comment 'universally unique identifier, usually a tag URI'*/,
562 created timestamp not null /* comment 'date the notice record was created'*/ ,
563 deleted timestamp not null DEFAULT CURRENT_TIMESTAMP /* comment 'date the notice record was created'*/
566 CREATE index deleted_notice_profile_id_idx on deleted_notice (profile_id);
568 /* Textsearch stuff */
570 create index textsearch_idx on profile using gist(textsearch);
571 create index noticecontent_idx on notice using gist(to_tsvector('english',content));
572 create trigger textsearchupdate before insert or update on profile for each row
573 execute procedure tsvector_update_trigger(textsearch, 'pg_catalog.english', nickname, fullname, location, bio, homepage);
575 create table config (
577 section varchar(32) /* comment 'configuration section'*/,
578 setting varchar(32) /* comment 'configuration setting'*/,
579 value varchar(255) /* comment 'configuration value'*/,
581 primary key (section, setting)
585 create table profile_role (
587 profile_id integer not null /* comment 'account having the role'*/ references profile (id),
588 role varchar(32) not null /* comment 'string representing the role'*/,
589 created timestamp /* not null comment 'date the role was granted'*/,
591 primary key (profile_id, role)
595 create table location_namespace (
597 id integer /*comment 'identity for this namespace'*/,
598 description text /* comment 'description of the namespace'*/ ,
599 created integer not null /*comment 'date the record was created*/ ,
600 /* modified timestamp comment 'date this record was modified',*/
605 create table login_token (
606 user_id integer not null /* comment 'user owning this token'*/ references "user" (id),
607 token char(32) not null /* comment 'token useable for logging in'*/,
608 created timestamp not null DEFAULT CURRENT_TIMESTAMP /* comment 'date this record was created'*/,
609 modified timestamp /* comment 'date this record was modified'*/,
611 primary key (user_id)
614 create table user_location_prefs (
615 user_id integer not null /* comment 'user who has the preference' */ references "user" (id),
616 share_location integer default 1 /* comment 'Whether to share location data' */,
617 created timestamp not null DEFAULT CURRENT_TIMESTAMP /* comment 'date this record was created' */,
618 modified timestamp /* comment 'date this record was modified' */,
620 primary key (user_id)
625 user_id integer not null /* comment 'user receiving the notice' */ references "user" (id),
626 notice_ids bytea /* comment 'packed list of notice ids' */,
628 primary key (user_id)
632 create sequence conversation_seq;
633 create table conversation (
634 id bigint default nextval('conversation_seq') primary key /* comment 'unique identifier' */,
635 uri varchar(225) unique /* comment 'URI of the conversation' */,
636 created timestamp not null DEFAULT CURRENT_TIMESTAMP /* comment 'date this record was created' */,
637 modified timestamp /* comment 'date this record was modified' */
640 create table local_group (
642 group_id integer primary key /* comment 'group represented' */ references user_group (id),
643 nickname varchar(64) unique /* comment 'group represented' */,
645 created timestamp not null DEFAULT CURRENT_TIMESTAMP /* comment 'date this record was created' */,
646 modified timestamp /* comment 'date this record was modified' */