1 /* local and remote users have profiles */
4 id integer auto_increment 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 created datetime not null comment 'date this record was created',
12 modified timestamp comment 'date this record was modified',
14 index profile_nickname_idx (nickname),
15 FULLTEXT(nickname, fullname, location, bio, homepage)
16 ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_general_ci;
19 profile_id integer not null comment 'foreign key to profile table' references profile (id),
20 original boolean default false comment 'uploaded by user or generated?',
21 width integer not null comment 'image width',
22 height integer not null comment 'image height',
23 mediatype varchar(32) not null comment 'file type',
24 filename varchar(255) null comment 'local filename, if local',
25 url varchar(255) unique key comment 'avatar location',
26 created datetime not null comment 'date this record was created',
27 modified timestamp comment 'date this record was modified',
29 constraint primary key (profile_id, width, height),
30 index avatar_profile_id_idx (profile_id)
31 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
33 create table sms_carrier (
34 id integer primary key comment 'primary key for SMS carrier',
35 name varchar(64) unique key comment 'name of the carrier',
36 email_pattern varchar(255) not null comment 'sprintf pattern for making an email address from a phone number',
37 created datetime not null comment 'date this record was created',
38 modified timestamp comment 'date this record was modified'
39 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
44 id integer primary key comment 'foreign key to profile table' references profile (id),
45 nickname varchar(64) unique key comment 'nickname or username, duped in profile',
46 password varchar(255) comment 'salted password, can be null for OpenID users',
47 email varchar(255) unique key comment 'email address for password recovery etc.',
48 incomingemail varchar(255) unique key comment 'email address for post-by-email',
49 emailnotifysub tinyint default 1 comment 'Notify by email of subscriptions',
50 emailnotifyfav tinyint default 1 comment 'Notify by email of favorites',
51 emailnotifynudge tinyint default 1 comment 'Notify by email of nudges',
52 emailnotifymsg tinyint default 1 comment 'Notify by email of direct messages',
53 emailnotifyattn tinyint default 1 comment 'Notify by email of @-replies',
54 emailmicroid tinyint default 1 comment 'whether to publish email microid',
55 language varchar(50) comment 'preferred language',
56 timezone varchar(50) comment 'timezone',
57 emailpost tinyint default 1 comment 'Post by email',
58 jabber varchar(255) unique key comment 'jabber ID for notices',
59 jabbernotify tinyint default 0 comment 'whether to send notices to jabber',
60 jabberreplies tinyint default 0 comment 'whether to send notices to jabber on replies',
61 jabbermicroid tinyint default 1 comment 'whether to publish xmpp microid',
62 updatefrompresence tinyint default 0 comment 'whether to record updates from Jabber presence notices',
63 sms varchar(64) unique key comment 'sms phone number',
64 carrier integer comment 'foreign key to sms_carrier' references sms_carrier (id),
65 smsnotify tinyint default 0 comment 'whether to send notices to SMS',
66 smsreplies tinyint default 0 comment 'whether to send notices to SMS on replies',
67 smsemail varchar(255) comment 'built from sms and carrier',
68 uri varchar(255) unique key comment 'universally unique identifier, usually a tag URI',
69 autosubscribe tinyint default 0 comment 'automatically subscribe to users who subscribe to us',
70 urlshorteningservice varchar(50) default 'ur1.ca' comment 'service to use for auto-shortening URLs',
71 inboxed tinyint default 0 comment 'has an inbox been created for this user?',
72 created datetime not null comment 'date this record was created',
73 modified timestamp comment 'date this record was modified',
75 index user_smsemail_idx (smsemail)
76 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_general_ci;
80 create table remote_profile (
81 id integer primary key comment 'foreign key to profile table' references profile (id),
82 uri varchar(255) unique key comment 'universally unique identifier, usually a tag URI',
83 postnoticeurl varchar(255) comment 'URL we use for posting notices',
84 updateprofileurl varchar(255) comment 'URL we use for updates to this profile',
85 created datetime not null comment 'date this record was created',
86 modified timestamp comment 'date this record was modified'
87 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
89 create table subscription (
90 subscriber integer not null comment 'profile listening',
91 subscribed integer not null comment 'profile being listened to',
92 jabber tinyint default 1 comment 'deliver jabber messages',
93 sms tinyint default 1 comment 'deliver sms messages',
94 token varchar(255) comment 'authorization token',
95 secret varchar(255) comment 'token secret',
96 created datetime not null comment 'date this record was created',
97 modified timestamp comment 'date this record was modified',
99 constraint primary key (subscriber, subscribed),
100 index subscription_subscriber_idx (subscriber),
101 index subscription_subscribed_idx (subscribed),
102 index subscription_token_idx (token)
103 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
105 create table notice (
106 id integer auto_increment primary key comment 'unique identifier',
107 profile_id integer not null comment 'who made the update' references profile (id),
108 uri varchar(255) unique key comment 'universally unique identifier, usually a tag URI',
109 content varchar(140) comment 'update content',
110 rendered text comment 'HTML version of the content',
111 url varchar(255) comment 'URL of any attachment (image, video, bookmark, whatever)',
112 created datetime not null comment 'date this record was created',
113 modified timestamp comment 'date this record was modified',
114 reply_to integer comment 'notice replied to (usually a guess)' references notice (id),
115 is_local tinyint default 0 comment 'notice was generated by a user',
116 source varchar(32) comment 'source of comment, like "web", "im", or "clientname"',
118 index notice_profile_id_idx (profile_id),
119 index notice_created_idx (created),
121 ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_general_ci;
123 create table notice_source (
124 code varchar(32) primary key not null comment 'source code',
125 name varchar(255) not null comment 'name of the source',
126 url varchar(255) not null comment 'url to link to',
127 created datetime not null comment 'date this record was created',
128 modified timestamp comment 'date this record was modified'
129 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
132 notice_id integer not null comment 'notice that is the reply' references notice (id),
133 profile_id integer not null comment 'profile replied to' references profile (id),
134 modified timestamp not null comment 'date this record was modified',
135 replied_id integer comment 'notice replied to (not used, see notice.reply_to)',
137 constraint primary key (notice_id, profile_id),
138 index reply_notice_id_idx (notice_id),
139 index reply_profile_id_idx (profile_id),
140 index reply_replied_id_idx (replied_id)
142 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
145 notice_id integer not null comment 'notice that is the favorite' references notice (id),
146 user_id integer not null comment 'user who likes this notice' references user (id),
147 modified timestamp not null comment 'date this record was modified',
149 constraint primary key (notice_id, user_id),
150 index fave_notice_id_idx (notice_id),
151 index fave_user_id_idx (user_id),
152 index fave_modified_idx (modified)
154 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
156 /* tables for OAuth */
158 create table consumer (
159 consumer_key varchar(255) primary key comment 'unique identifier, root URL',
160 seed char(32) not null comment 'seed for new tokens by this consumer',
162 created datetime not null comment 'date this record was created',
163 modified timestamp comment 'date this record was modified'
164 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
167 consumer_key varchar(255) not null comment 'unique identifier, root URL' references consumer (consumer_key),
168 tok char(32) not null comment 'identifying value',
169 secret char(32) not null comment 'secret value',
170 type tinyint not null default 0 comment 'request or access',
171 state tinyint default 0 comment 'for requests, 0 = initial, 1 = authorized, 2 = used',
173 created datetime not null comment 'date this record was created',
174 modified timestamp comment 'date this record was modified',
176 constraint primary key (consumer_key, tok)
177 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
180 consumer_key varchar(255) not null comment 'unique identifier, root URL',
181 tok char(32) null comment 'buggy old value, ignored',
182 nonce char(32) not null comment 'nonce',
183 ts datetime not null comment 'timestamp sent',
185 created datetime not null comment 'date this record was created',
186 modified timestamp comment 'date this record was modified',
188 constraint primary key (consumer_key, ts, nonce)
189 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
191 /* One-to-many relationship of user to openid_url */
193 create table user_openid (
194 canonical varchar(255) primary key comment 'Canonical true URL',
195 display varchar(255) not null unique key comment 'URL for viewing, may be different from canonical',
196 user_id integer not null comment 'user owning this URL' references user (id),
197 created datetime not null comment 'date this record was created',
198 modified timestamp comment 'date this record was modified',
200 index user_openid_user_id_idx (user_id)
201 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
203 /* These are used by JanRain OpenID library */
205 create table oid_associations (
207 handle VARCHAR(255) character set latin1,
211 assoc_type VARCHAR(64),
212 PRIMARY KEY (server_url(255), handle)
213 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
215 create table oid_nonces (
216 server_url VARCHAR(2047),
219 UNIQUE (server_url(255), timestamp, salt)
220 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
222 create table confirm_address (
223 code varchar(32) not null primary key comment 'good random code',
224 user_id integer not null comment 'user who requested confirmation' references user (id),
225 address varchar(255) not null comment 'address (email, Jabber, SMS, etc.)',
226 address_extra varchar(255) not null comment 'carrier ID, for SMS',
227 address_type varchar(8) not null comment 'address type ("email", "jabber", "sms")',
228 claimed datetime comment 'date this was claimed for queueing',
229 sent datetime comment 'date this was sent for queueing',
230 modified timestamp comment 'date this record was modified'
231 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
233 create table remember_me (
234 code varchar(32) not null primary key comment 'good random code',
235 user_id integer not null comment 'user who is logged in' references user (id),
236 modified timestamp comment 'date this record was modified'
237 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
239 create table queue_item (
241 notice_id integer not null comment 'notice queued' references notice (id),
242 transport varchar(8) not null comment 'queue for what? "email", "jabber", "sms", "irc", ...',
243 created datetime not null comment 'date this record was created',
244 claimed datetime comment 'date this item was claimed',
246 constraint primary key (notice_id, transport),
247 index queue_item_created_idx (created)
249 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
252 create table notice_tag (
253 tag varchar( 64 ) not null comment 'hash tag associated with this notice',
254 notice_id integer not null comment 'notice tagged' references notice (id),
255 created datetime not null comment 'date this record was created',
257 constraint primary key (tag, notice_id),
258 index notice_tag_created_idx (created),
259 index notice_tag_notice_id_idx (notice_id)
260 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
262 /* Synching with foreign services */
264 create table foreign_service (
265 id int not null primary key comment 'numeric key for service',
266 name varchar(32) not null unique key comment 'name of the service',
267 description varchar(255) comment 'description',
268 created datetime not null comment 'date this record was created',
269 modified timestamp comment 'date this record was modified'
270 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
272 create table foreign_user (
273 id int not null comment 'unique numeric key on foreign service',
274 service int not null comment 'foreign key to service' references foreign_service(id),
275 uri varchar(255) not null unique key comment 'identifying URI',
276 nickname varchar(255) comment 'nickname on foreign service',
277 created datetime not null comment 'date this record was created',
278 modified timestamp comment 'date this record was modified',
280 constraint primary key (id, service)
281 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
283 create table foreign_link (
284 user_id int comment 'link to user on this system, if exists' references user (id),
285 foreign_id int comment 'link ' references foreign_user(id),
286 service int not null comment 'foreign key to service' references foreign_service(id),
287 credentials varchar(255) comment 'authc credentials, typically a password',
288 noticesync tinyint not null default 1 comment 'notice synchronization, bit 1 = sync outgoing, bit 2 = sync incoming, bit 3 = filter local replies',
289 friendsync tinyint not null default 2 comment 'friend synchronization, bit 1 = sync outgoing, bit 2 = sync incoming',
290 profilesync tinyint not null default 1 comment 'profile synchronization, bit 1 = sync outgoing, bit 2 = sync incoming',
291 created datetime not null comment 'date this record was created',
292 modified timestamp comment 'date this record was modified',
294 constraint primary key (user_id, foreign_id, service),
295 index foreign_user_user_id_idx (user_id)
296 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
298 create table foreign_subscription (
299 service int not null comment 'service where relationship happens' references foreign_service(id),
300 subscriber int not null comment 'subscriber on foreign service' references foreign_user (id),
301 subscribed int not null comment 'subscribed user' references foreign_user (id),
302 created datetime not null comment 'date this record was created',
304 constraint primary key (service, subscriber, subscribed),
305 index foreign_subscription_subscriber_idx (subscriber),
306 index foreign_subscription_subscribed_idx (subscribed)
307 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
309 create table invitation (
310 code varchar(32) not null primary key comment 'random code for an invitation',
311 user_id int not null comment 'who sent the invitation' references user (id),
312 address varchar(255) not null comment 'invitation sent to',
313 address_type varchar(8) not null comment 'address type ("email", "jabber", "sms")',
314 created datetime not null comment 'date this record was created',
316 index invitation_address_idx (address, address_type),
317 index invitation_user_id_idx (user_id)
318 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
320 create table message (
321 id integer auto_increment primary key comment 'unique identifier',
322 uri varchar(255) unique key comment 'universally unique identifier',
323 from_profile integer not null comment 'who the message is from' references profile (id),
324 to_profile integer not null comment 'who the message is to' references profile (id),
325 content varchar(140) comment 'message content',
326 rendered text comment 'HTML version of the content',
327 url varchar(255) comment 'URL of any attachment (image, video, bookmark, whatever)',
328 created datetime not null comment 'date this record was created',
329 modified timestamp comment 'date this record was modified',
330 source varchar(32) comment 'source of comment, like "web", "im", or "clientname"',
332 index message_from_idx (from_profile),
333 index message_to_idx (to_profile),
334 index message_created_idx (created)
335 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_general_ci;
337 create table notice_inbox (
338 user_id integer not null comment 'user receiving the message' references user (id),
339 notice_id integer not null comment 'notice received' references notice (id),
340 created datetime not null comment 'date the notice was created',
341 source tinyint default 1 comment 'reason it is in the inbox, 1=subscription',
343 constraint primary key (user_id, notice_id),
344 index notice_inbox_notice_id_idx (notice_id)
345 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
347 create table profile_tag (
348 tagger integer not null comment 'user making the tag' references user (id),
349 tagged integer not null comment 'profile tagged' references profile (id),
350 tag varchar(64) not null comment 'hash tag associated with this notice',
351 modified timestamp comment 'date the tag was added',
353 constraint primary key (tagger, tagged, tag),
354 index profile_tag_modified_idx (modified),
355 index profile_tag_tagger_tag_idx (tagger, tag),
356 index profile_tag_tagged_idx (tagged)
357 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
359 create table profile_block (
360 blocker integer not null comment 'user making the block' references user (id),
361 blocked integer not null comment 'profile that is blocked' references profile (id),
362 modified timestamp comment 'date of blocking',
364 constraint primary key (blocker, blocked)
366 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
368 create table user_group (
369 id integer auto_increment primary key comment 'unique identifier',
371 nickname varchar(64) unique key comment 'nickname for addressing',
372 fullname varchar(255) comment 'display name',
373 homepage varchar(255) comment 'URL, cached so we dont regenerate',
374 description varchar(140) comment 'descriptive biography',
375 location varchar(255) comment 'related physical location, if any',
377 original_logo varchar(255) comment 'original size logo',
378 homepage_logo varchar(255) comment 'homepage (profile) size logo',
379 stream_logo varchar(255) comment 'stream-sized logo',
380 mini_logo varchar(255) comment 'mini logo',
382 created datetime not null comment 'date this record was created',
383 modified timestamp comment 'date this record was modified',
385 index user_group_nickname_idx (nickname)
387 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_general_ci;
389 create table group_member (
390 group_id integer not null comment 'foreign key to user_group' references user_group (id),
391 profile_id integer not null comment 'foreign key to profile table' references profile (id),
392 is_admin boolean default false comment 'is this user an admin?',
394 created datetime not null comment 'date this record was created',
395 modified timestamp comment 'date this record was modified',
397 constraint primary key (group_id, profile_id),
398 index group_member_profile_id_idx (profile_id),
399 index group_member_created_idx (created)
401 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
403 create table related_group (
404 group_id integer not null comment 'foreign key to user_group' references user_group (id),
405 related_group_id integer not null comment 'foreign key to user_group' references user_group (id),
407 created datetime not null comment 'date this record was created',
409 constraint primary key (group_id, related_group_id)
411 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
413 create table group_inbox (
414 group_id integer not null comment 'group receiving the message' references user_group (id),
415 notice_id integer not null comment 'notice received' references notice (id),
416 created datetime not null comment 'date the notice was created',
418 constraint primary key (group_id, notice_id),
419 index group_inbox_created_idx (created)
421 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;