1 /* local and remote users have profiles */
5 id integer auto_increment 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 text comment 'descriptive biography',
11 location varchar(255) comment 'physical location',
12 lat decimal(10,7) comment 'latitude',
13 lon decimal(10,7) comment 'longitude',
14 location_id integer comment 'location id if possible',
15 location_ns integer comment 'namespace for location',
17 created datetime not null comment 'date this record was created',
18 modified timestamp comment 'date this record was modified',
20 index profile_nickname_idx (nickname),
21 FULLTEXT(nickname, fullname, location, bio, homepage)
22 ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_general_ci;
25 profile_id integer not null comment 'foreign key to profile table' references profile (id),
26 original boolean default false comment 'uploaded by user or generated?',
27 width integer not null comment 'image width',
28 height integer not null comment 'image height',
29 mediatype varchar(32) not null comment 'file type',
30 filename varchar(255) null comment 'local filename, if local',
31 url varchar(255) unique key comment 'avatar location',
32 created datetime not null comment 'date this record was created',
33 modified timestamp comment 'date this record was modified',
35 constraint primary key (profile_id, width, height),
36 index avatar_profile_id_idx (profile_id)
37 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
39 create table sms_carrier (
40 id integer primary key comment 'primary key for SMS carrier',
41 name varchar(64) unique key comment 'name of the carrier',
42 email_pattern varchar(255) not null comment 'sprintf pattern for making an email address from a phone number',
43 created datetime not null comment 'date this record was created',
44 modified timestamp comment 'date this record was modified'
45 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
51 id integer primary key comment 'foreign key to profile table' references profile (id),
52 nickname varchar(64) unique key comment 'nickname or username, duped in profile',
53 password varchar(255) comment 'salted password, can be null for OpenID users',
54 email varchar(255) unique key comment 'email address for password recovery etc.',
55 incomingemail varchar(255) unique key comment 'email address for post-by-email',
56 emailnotifysub tinyint default 1 comment 'Notify by email of subscriptions',
57 emailnotifyfav tinyint default 1 comment 'Notify by email of favorites',
58 emailnotifynudge tinyint default 1 comment 'Notify by email of nudges',
59 emailnotifymsg tinyint default 1 comment 'Notify by email of direct messages',
60 emailnotifyattn tinyint default 1 comment 'Notify by email of @-replies',
61 emailmicroid tinyint default 1 comment 'whether to publish email microid',
62 language varchar(50) comment 'preferred language',
63 timezone varchar(50) comment 'timezone',
64 emailpost tinyint default 1 comment 'Post by email',
65 jabber varchar(255) unique key comment 'jabber ID for notices',
66 jabbernotify tinyint default 0 comment 'whether to send notices to jabber',
67 jabberreplies tinyint default 0 comment 'whether to send notices to jabber on replies',
68 jabbermicroid tinyint default 1 comment 'whether to publish xmpp microid',
69 updatefrompresence tinyint default 0 comment 'whether to record updates from Jabber presence notices',
70 sms varchar(64) unique key comment 'sms phone number',
71 carrier integer comment 'foreign key to sms_carrier' references sms_carrier (id),
72 smsnotify tinyint default 0 comment 'whether to send notices to SMS',
73 smsreplies tinyint default 0 comment 'whether to send notices to SMS on replies',
74 smsemail varchar(255) comment 'built from sms and carrier',
75 uri varchar(255) unique key comment 'universally unique identifier, usually a tag URI',
76 autosubscribe tinyint default 0 comment 'automatically subscribe to users who subscribe to us',
77 urlshorteningservice varchar(50) default 'ur1.ca' comment 'service to use for auto-shortening URLs',
78 inboxed tinyint default 0 comment 'has an inbox been created for this user?',
79 design_id integer comment 'id of a design' references design(id),
80 viewdesigns tinyint default 1 comment 'whether to view user-provided designs',
82 created datetime not null comment 'date this record was created',
83 modified timestamp comment 'date this record was modified',
85 index user_smsemail_idx (smsemail)
86 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_general_ci;
90 create table remote_profile (
91 id integer primary key comment 'foreign key to profile table' references profile (id),
92 uri varchar(255) unique key comment 'universally unique identifier, usually a tag URI',
93 postnoticeurl varchar(255) comment 'URL we use for posting notices',
94 updateprofileurl varchar(255) comment 'URL we use for updates to this profile',
95 created datetime not null comment 'date this record was created',
96 modified timestamp comment 'date this record was modified'
97 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
99 create table subscription (
100 subscriber integer not null comment 'profile listening',
101 subscribed integer not null comment 'profile being listened to',
102 jabber tinyint default 1 comment 'deliver jabber messages',
103 sms tinyint default 1 comment 'deliver sms messages',
104 token varchar(255) comment 'authorization token',
105 secret varchar(255) comment 'token secret',
106 created datetime not null comment 'date this record was created',
107 modified timestamp comment 'date this record was modified',
109 constraint primary key (subscriber, subscribed),
110 index subscription_subscriber_idx (subscriber, created),
111 index subscription_subscribed_idx (subscribed, created),
112 index subscription_token_idx (token)
113 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
115 create table notice (
116 id integer auto_increment primary key comment 'unique identifier',
117 profile_id integer not null comment 'who made the update' references profile (id),
118 uri varchar(255) unique key comment 'universally unique identifier, usually a tag URI',
119 content text comment 'update content',
120 rendered text comment 'HTML version of the content',
121 url varchar(255) comment 'URL of any attachment (image, video, bookmark, whatever)',
122 created datetime not null comment 'date this record was created',
123 modified timestamp comment 'date this record was modified',
124 reply_to integer comment 'notice replied to (usually a guess)' references notice (id),
125 is_local tinyint default 0 comment 'notice was generated by a user',
126 source varchar(32) comment 'source of comment, like "web", "im", or "clientname"',
127 conversation integer comment 'id of root notice in this conversation' references notice (id),
128 lat decimal(10,7) comment 'latitude',
129 lon decimal(10,7) comment 'longitude',
130 location_id integer comment 'location id if possible',
131 location_ns integer comment 'namespace for location',
133 index notice_profile_id_idx (profile_id),
134 index notice_conversation_idx (conversation),
135 index notice_created_idx (created),
136 index notice_replyto_idx (reply_to),
138 ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_general_ci;
140 create table notice_source (
141 code varchar(32) primary key not null comment 'source code',
142 name varchar(255) not null comment 'name of the source',
143 url varchar(255) not null comment 'url to link to',
144 created datetime not null comment 'date this record was created',
145 modified timestamp comment 'date this record was modified'
146 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
149 notice_id integer not null comment 'notice that is the reply' references notice (id),
150 profile_id integer not null comment 'profile replied to' references profile (id),
151 modified timestamp not null comment 'date this record was modified',
152 replied_id integer comment 'notice replied to (not used, see notice.reply_to)',
154 constraint primary key (notice_id, profile_id),
155 index reply_notice_id_idx (notice_id),
156 index reply_profile_id_idx (profile_id),
157 index reply_replied_id_idx (replied_id)
159 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
162 notice_id integer not null comment 'notice that is the favorite' references notice (id),
163 user_id integer not null comment 'user who likes this notice' references user (id),
164 modified timestamp not null comment 'date this record was modified',
166 constraint primary key (notice_id, user_id),
167 index fave_notice_id_idx (notice_id),
168 index fave_user_id_idx (user_id,modified),
169 index fave_modified_idx (modified)
171 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
173 /* tables for OAuth */
175 create table consumer (
176 consumer_key varchar(255) primary key comment 'unique identifier, root URL',
177 seed char(32) not null comment 'seed for new tokens by this consumer',
179 created datetime not null comment 'date this record was created',
180 modified timestamp comment 'date this record was modified'
181 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
184 consumer_key varchar(255) not null comment 'unique identifier, root URL' references consumer (consumer_key),
185 tok char(32) not null comment 'identifying value',
186 secret char(32) not null comment 'secret value',
187 type tinyint not null default 0 comment 'request or access',
188 state tinyint default 0 comment 'for requests, 0 = initial, 1 = authorized, 2 = used',
190 created datetime not null comment 'date this record was created',
191 modified timestamp comment 'date this record was modified',
193 constraint primary key (consumer_key, tok)
194 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
197 consumer_key varchar(255) not null comment 'unique identifier, root URL',
198 tok char(32) null comment 'buggy old value, ignored',
199 nonce char(32) not null comment 'nonce',
200 ts datetime not null comment 'timestamp sent',
202 created datetime not null comment 'date this record was created',
203 modified timestamp comment 'date this record was modified',
205 constraint primary key (consumer_key, ts, nonce)
206 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
208 /* These are used by JanRain OpenID library */
210 create table oid_associations (
212 handle VARCHAR(255) character set latin1,
216 assoc_type VARCHAR(64),
217 PRIMARY KEY (server_url(255), handle)
218 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
220 create table oid_nonces (
221 server_url VARCHAR(2047),
224 UNIQUE (server_url(255), timestamp, salt)
225 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
227 create table confirm_address (
228 code varchar(32) not null primary key comment 'good random code',
229 user_id integer not null comment 'user who requested confirmation' references user (id),
230 address varchar(255) not null comment 'address (email, Jabber, SMS, etc.)',
231 address_extra varchar(255) not null comment 'carrier ID, for SMS',
232 address_type varchar(8) not null comment 'address type ("email", "jabber", "sms")',
233 claimed datetime comment 'date this was claimed for queueing',
234 sent datetime comment 'date this was sent for queueing',
235 modified timestamp comment 'date this record was modified'
236 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
238 create table remember_me (
239 code varchar(32) not null primary key comment 'good random code',
240 user_id integer not null comment 'user who is logged in' references user (id),
241 modified timestamp comment 'date this record was modified'
242 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
244 create table queue_item (
246 notice_id integer not null comment 'notice queued' references notice (id),
247 transport varchar(8) not null comment 'queue for what? "email", "jabber", "sms", "irc", ...',
248 created datetime not null comment 'date this record was created',
249 claimed datetime comment 'date this item was claimed',
251 constraint primary key (notice_id, transport),
252 index queue_item_created_idx (created)
254 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
257 create table notice_tag (
258 tag varchar( 64 ) not null comment 'hash tag associated with this notice',
259 notice_id integer not null comment 'notice tagged' references notice (id),
260 created datetime not null comment 'date this record was created',
262 constraint primary key (tag, notice_id),
263 index notice_tag_created_idx (created),
264 index notice_tag_notice_id_idx (notice_id)
265 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
267 /* Synching with foreign services */
269 create table foreign_service (
270 id int not null primary key comment 'numeric key for service',
271 name varchar(32) not null unique key comment 'name of the service',
272 description varchar(255) comment 'description',
273 created datetime not null comment 'date this record was created',
274 modified timestamp comment 'date this record was modified'
275 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
277 create table foreign_user (
278 id bigint not null comment 'unique numeric key on foreign service',
279 service int not null comment 'foreign key to service' references foreign_service(id),
280 uri varchar(255) not null unique key comment 'identifying URI',
281 nickname varchar(255) comment 'nickname on foreign service',
282 created datetime not null comment 'date this record was created',
283 modified timestamp comment 'date this record was modified',
285 constraint primary key (id, service)
286 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
288 create table foreign_link (
289 user_id int comment 'link to user on this system, if exists' references user (id),
290 foreign_id bigint unsigned comment 'link to user on foreign service, if exists' references foreign_user(id),
291 service int not null comment 'foreign key to service' references foreign_service(id),
292 credentials varchar(255) comment 'authc credentials, typically a password',
293 noticesync tinyint not null default 1 comment 'notice synchronization, bit 1 = sync outgoing, bit 2 = sync incoming, bit 3 = filter local replies',
294 friendsync tinyint not null default 2 comment 'friend synchronization, bit 1 = sync outgoing, bit 2 = sync incoming',
295 profilesync tinyint not null default 1 comment 'profile synchronization, bit 1 = sync outgoing, bit 2 = sync incoming',
296 last_noticesync datetime default null comment 'last time notices were imported',
297 last_friendsync datetime default null comment 'last time friends were imported',
298 created datetime not null comment 'date this record was created',
299 modified timestamp comment 'date this record was modified',
301 constraint primary key (user_id, foreign_id, service),
302 index foreign_user_user_id_idx (user_id)
303 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
305 create table foreign_subscription (
306 service int not null comment 'service where relationship happens' references foreign_service(id),
307 subscriber int not null comment 'subscriber on foreign service' references foreign_user (id),
308 subscribed int not null comment 'subscribed user' references foreign_user (id),
309 created datetime not null comment 'date this record was created',
311 constraint primary key (service, subscriber, subscribed),
312 index foreign_subscription_subscriber_idx (subscriber),
313 index foreign_subscription_subscribed_idx (subscribed)
314 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
316 create table invitation (
317 code varchar(32) not null primary key comment 'random code for an invitation',
318 user_id int not null comment 'who sent the invitation' references user (id),
319 address varchar(255) not null comment 'invitation sent to',
320 address_type varchar(8) not null comment 'address type ("email", "jabber", "sms")',
321 created datetime not null comment 'date this record was created',
323 index invitation_address_idx (address, address_type),
324 index invitation_user_id_idx (user_id)
325 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
327 create table message (
328 id integer auto_increment primary key comment 'unique identifier',
329 uri varchar(255) unique key comment 'universally unique identifier',
330 from_profile integer not null comment 'who the message is from' references profile (id),
331 to_profile integer not null comment 'who the message is to' references profile (id),
332 content text comment 'message content',
333 rendered text comment 'HTML version of the content',
334 url varchar(255) comment 'URL of any attachment (image, video, bookmark, whatever)',
335 created datetime not null comment 'date this record was created',
336 modified timestamp comment 'date this record was modified',
337 source varchar(32) comment 'source of comment, like "web", "im", or "clientname"',
339 index message_from_idx (from_profile),
340 index message_to_idx (to_profile),
341 index message_created_idx (created)
342 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_general_ci;
344 create table notice_inbox (
345 user_id integer not null comment 'user receiving the message' references user (id),
346 notice_id integer not null comment 'notice received' references notice (id),
347 created datetime not null comment 'date the notice was created',
348 source tinyint default 1 comment 'reason it is in the inbox, 1=subscription',
350 constraint primary key (user_id, notice_id),
351 index notice_inbox_notice_id_idx (notice_id)
352 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
354 create table profile_tag (
355 tagger integer not null comment 'user making the tag' references user (id),
356 tagged integer not null comment 'profile tagged' references profile (id),
357 tag varchar(64) not null comment 'hash tag associated with this notice',
358 modified timestamp comment 'date the tag was added',
360 constraint primary key (tagger, tagged, tag),
361 index profile_tag_modified_idx (modified),
362 index profile_tag_tagger_tag_idx (tagger, tag),
363 index profile_tag_tagged_idx (tagged)
364 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
366 create table profile_block (
367 blocker integer not null comment 'user making the block' references user (id),
368 blocked integer not null comment 'profile that is blocked' references profile (id),
369 modified timestamp comment 'date of blocking',
371 constraint primary key (blocker, blocked)
373 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
375 create table user_group (
376 id integer auto_increment primary key comment 'unique identifier',
378 nickname varchar(64) unique key comment 'nickname for addressing',
379 fullname varchar(255) comment 'display name',
380 homepage varchar(255) comment 'URL, cached so we dont regenerate',
381 description text comment 'group description',
382 location varchar(255) comment 'related physical location, if any',
384 original_logo varchar(255) comment 'original size logo',
385 homepage_logo varchar(255) comment 'homepage (profile) size logo',
386 stream_logo varchar(255) comment 'stream-sized logo',
387 mini_logo varchar(255) comment 'mini logo',
388 design_id integer comment 'id of a design' references design(id),
390 created datetime not null comment 'date this record was created',
391 modified timestamp comment 'date this record was modified',
393 index user_group_nickname_idx (nickname)
395 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_general_ci;
397 create table group_member (
398 group_id integer not null comment 'foreign key to user_group' references user_group (id),
399 profile_id integer not null comment 'foreign key to profile table' references profile (id),
400 is_admin boolean default false comment 'is this user an admin?',
402 created datetime not null comment 'date this record was created',
403 modified timestamp comment 'date this record was modified',
405 constraint primary key (group_id, profile_id),
406 index group_member_profile_id_idx (profile_id),
407 index group_member_created_idx (created)
409 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
411 create table related_group (
412 group_id integer not null comment 'foreign key to user_group' references user_group (id),
413 related_group_id integer not null comment 'foreign key to user_group' references user_group (id),
415 created datetime not null comment 'date this record was created',
417 constraint primary key (group_id, related_group_id)
419 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
421 create table group_inbox (
422 group_id integer not null comment 'group receiving the message' references user_group (id),
423 notice_id integer not null comment 'notice received' references notice (id),
424 created datetime not null comment 'date the notice was created',
426 constraint primary key (group_id, notice_id),
427 index group_inbox_created_idx (created)
429 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
433 id integer primary key auto_increment,
434 url varchar(255) comment 'destination URL after following redirections',
435 mimetype varchar(50) comment 'mime type of resource',
436 size integer comment 'size of resource when available',
437 title varchar(255) comment 'title of resource when available',
438 date integer(11) comment 'date of resource according to http query',
439 protected integer(1) comment 'true when URL is private (needs login)',
440 filename varchar(255) comment 'if a local file, name of the file',
442 modified timestamp comment 'date this record was modified',
445 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_general_ci;
447 create table file_oembed (
448 file_id integer primary key comment 'oEmbed for that URL/file' references file (id),
449 version varchar(20) comment 'oEmbed spec. version',
450 type varchar(20) comment 'oEmbed type: photo, video, link, rich',
451 mimetype varchar(50) comment 'mime type of resource',
452 provider varchar(50) comment 'name of this oEmbed provider',
453 provider_url varchar(255) comment 'URL of this oEmbed provider',
454 width integer comment 'width of oEmbed resource when available',
455 height integer comment 'height of oEmbed resource when available',
456 html text comment 'html representation of this oEmbed resource when applicable',
457 title varchar(255) comment 'title of oEmbed resource when available',
458 author_name varchar(50) comment 'author name for this oEmbed resource',
459 author_url varchar(255) comment 'author URL for this oEmbed resource',
460 url varchar(255) comment 'URL for this oEmbed resource when applicable (photo, link)',
461 modified timestamp comment 'date this record was modified'
463 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_general_ci;
465 create table file_redirection (
467 url varchar(255) primary key comment 'short URL (or any other kind of redirect) for file (id)',
468 file_id integer comment 'short URL for what URL/file' references file (id),
469 redirections integer comment 'redirect count',
470 httpcode integer comment 'HTTP status code (20x, 30x, etc.)',
471 modified timestamp comment 'date this record was modified'
473 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
475 create table file_thumbnail (
477 file_id integer primary key comment 'thumbnail for what URL/file' references file (id),
478 url varchar(255) comment 'URL of thumbnail',
479 width integer comment 'width of thumbnail',
480 height integer comment 'height of thumbnail',
481 modified timestamp comment 'date this record was modified',
484 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
486 create table file_to_post (
488 file_id integer comment 'id of URL/file' references file (id),
489 post_id integer comment 'id of the notice it belongs to' references notice (id),
490 modified timestamp comment 'date this record was modified',
492 constraint primary key (file_id, post_id)
494 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
496 create table design (
497 id integer primary key auto_increment comment 'design ID',
498 backgroundcolor integer comment 'main background color',
499 contentcolor integer comment 'content area background color',
500 sidebarcolor integer comment 'sidebar background color',
501 textcolor integer comment 'text color',
502 linkcolor integer comment 'link color',
503 backgroundimage varchar(255) comment 'background image, if any',
504 disposition tinyint default 1 comment 'bit 1 = hide background image, bit 2 = display background image, bit 4 = tile background image'
505 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
507 create table group_block (
508 group_id integer not null comment 'group profile is blocked from' references user_group (id),
509 blocked integer not null comment 'profile that is blocked' references profile (id),
510 blocker integer not null comment 'user making the block' references user (id),
511 modified timestamp comment 'date of blocking',
513 constraint primary key (group_id, blocked)
515 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
517 create table group_alias (
519 alias varchar(64) primary key comment 'additional nickname for the group',
520 group_id integer not null comment 'group profile is blocked from' references user_group (id),
521 modified timestamp comment 'date alias was created',
523 index group_alias_group_id_idx (group_id)
525 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
527 create table session (
529 id varchar(32) primary key comment 'session ID',
530 session_data text comment 'session data',
531 created datetime not null comment 'date this record was created',
532 modified timestamp comment 'date this record was modified',
534 index session_modified_idx (modified)
536 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
538 create table deleted_notice (
540 id integer primary key comment 'identity of notice',
541 profile_id integer not null comment 'author of the notice',
542 uri varchar(255) unique key comment 'universally unique identifier, usually a tag URI',
543 created datetime not null comment 'date the notice record was created',
544 deleted datetime not null comment 'date the notice record was created',
546 index deleted_notice_profile_id_idx (profile_id)
548 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
550 create table config (
552 section varchar(32) comment 'configuration section',
553 setting varchar(32) comment 'configuration setting',
554 value varchar(255) comment 'configuration value',
556 constraint primary key (section, setting)
558 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
560 create table user_role (
562 user_id integer not null comment 'user having the role' references user (id),
563 role varchar(32) not null comment 'string representing the role',
564 created datetime not null comment 'date the role was granted',
566 constraint primary key (user_id, role)
568 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
570 create table location_namespace (
572 id integer primary key comment 'identity for this namespace',
573 description varchar(255) comment 'description of the namespace',
574 created datetime not null comment 'date the record was created',
575 modified timestamp comment 'date this record was modified'
577 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
579 create table login_token (
580 user_id integer not null comment 'user owning this token' references user (id),
581 token char(32) not null comment 'token useable for logging in',
582 created datetime not null comment 'date this record was created',
583 modified timestamp comment 'date this record was modified',
585 constraint primary key (user_id)
586 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;