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',
132 repeat_of integer comment 'notice this is a repeat of' references notice (id),
134 index notice_profile_id_idx (profile_id,created,id),
135 index notice_conversation_idx (conversation),
136 index notice_created_idx (created),
137 index notice_replyto_idx (reply_to),
138 index notice_repeatof_idx (repeat_of),
140 ) ENGINE=MyISAM CHARACTER SET utf8 COLLATE utf8_general_ci;
142 create table notice_source (
143 code varchar(32) primary key not null comment 'source code',
144 name varchar(255) not null comment 'name of the source',
145 url varchar(255) not null comment 'url to link to',
146 created datetime not null comment 'date this record was created',
147 modified timestamp comment 'date this record was modified'
148 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
151 notice_id integer not null comment 'notice that is the reply' references notice (id),
152 profile_id integer not null comment 'profile replied to' references profile (id),
153 modified timestamp not null comment 'date this record was modified',
154 replied_id integer comment 'notice replied to (not used, see notice.reply_to)',
156 constraint primary key (notice_id, profile_id),
157 index reply_notice_id_idx (notice_id),
158 index reply_profile_id_idx (profile_id),
159 index reply_replied_id_idx (replied_id)
161 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
164 notice_id integer not null comment 'notice that is the favorite' references notice (id),
165 user_id integer not null comment 'user who likes this notice' references user (id),
166 modified timestamp not null comment 'date this record was modified',
168 constraint primary key (notice_id, user_id),
169 index fave_notice_id_idx (notice_id),
170 index fave_user_id_idx (user_id,modified),
171 index fave_modified_idx (modified)
173 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
175 /* tables for OAuth */
177 create table consumer (
178 consumer_key varchar(255) primary key comment 'unique identifier, root URL',
179 seed char(32) not null comment 'seed for new tokens by this consumer',
181 created datetime not null comment 'date this record was created',
182 modified timestamp comment 'date this record was modified'
183 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
186 consumer_key varchar(255) not null comment 'unique identifier, root URL' references consumer (consumer_key),
187 tok char(32) not null comment 'identifying value',
188 secret char(32) not null comment 'secret value',
189 type tinyint not null default 0 comment 'request or access',
190 state tinyint default 0 comment 'for requests, 0 = initial, 1 = authorized, 2 = used',
192 created datetime not null comment 'date this record was created',
193 modified timestamp comment 'date this record was modified',
195 constraint primary key (consumer_key, tok)
196 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
199 consumer_key varchar(255) not null comment 'unique identifier, root URL',
200 tok char(32) null comment 'buggy old value, ignored',
201 nonce char(32) not null comment 'nonce',
202 ts datetime not null comment 'timestamp sent',
204 created datetime not null comment 'date this record was created',
205 modified timestamp comment 'date this record was modified',
207 constraint primary key (consumer_key, ts, nonce)
208 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
210 /* These are used by JanRain OpenID library */
212 create table oid_associations (
214 handle VARCHAR(255) character set latin1,
218 assoc_type VARCHAR(64),
219 PRIMARY KEY (server_url(255), handle)
220 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
222 create table oid_nonces (
223 server_url VARCHAR(2047),
226 UNIQUE (server_url(255), timestamp, salt)
227 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
229 create table confirm_address (
230 code varchar(32) not null primary key comment 'good random code',
231 user_id integer not null comment 'user who requested confirmation' references user (id),
232 address varchar(255) not null comment 'address (email, Jabber, SMS, etc.)',
233 address_extra varchar(255) not null comment 'carrier ID, for SMS',
234 address_type varchar(8) not null comment 'address type ("email", "jabber", "sms")',
235 claimed datetime comment 'date this was claimed for queueing',
236 sent datetime comment 'date this was sent for queueing',
237 modified timestamp comment 'date this record was modified'
238 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
240 create table remember_me (
241 code varchar(32) not null primary key comment 'good random code',
242 user_id integer not null comment 'user who is logged in' references user (id),
243 modified timestamp comment 'date this record was modified'
244 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
246 create table queue_item (
248 notice_id integer not null comment 'notice queued' references notice (id),
249 transport varchar(8) not null comment 'queue for what? "email", "jabber", "sms", "irc", ...',
250 created datetime not null comment 'date this record was created',
251 claimed datetime comment 'date this item was claimed',
253 constraint primary key (notice_id, transport),
254 index queue_item_created_idx (created)
256 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
259 create table notice_tag (
260 tag varchar( 64 ) not null comment 'hash tag associated with this notice',
261 notice_id integer not null comment 'notice tagged' references notice (id),
262 created datetime not null comment 'date this record was created',
264 constraint primary key (tag, notice_id),
265 index notice_tag_created_idx (created),
266 index notice_tag_notice_id_idx (notice_id)
267 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
269 /* Synching with foreign services */
271 create table foreign_service (
272 id int not null primary key comment 'numeric key for service',
273 name varchar(32) not null unique key comment 'name of the service',
274 description varchar(255) comment 'description',
275 created datetime not null comment 'date this record was created',
276 modified timestamp comment 'date this record was modified'
277 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
279 create table foreign_user (
280 id bigint not null comment 'unique numeric key on foreign service',
281 service int not null comment 'foreign key to service' references foreign_service(id),
282 uri varchar(255) not null unique key comment 'identifying URI',
283 nickname varchar(255) comment 'nickname on foreign service',
284 created datetime not null comment 'date this record was created',
285 modified timestamp comment 'date this record was modified',
287 constraint primary key (id, service)
288 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
290 create table foreign_link (
291 user_id int comment 'link to user on this system, if exists' references user (id),
292 foreign_id bigint unsigned comment 'link to user on foreign service, if exists' references foreign_user(id),
293 service int not null comment 'foreign key to service' references foreign_service(id),
294 credentials varchar(255) comment 'authc credentials, typically a password',
295 noticesync tinyint not null default 1 comment 'notice synchronization, bit 1 = sync outgoing, bit 2 = sync incoming, bit 3 = filter local replies',
296 friendsync tinyint not null default 2 comment 'friend synchronization, bit 1 = sync outgoing, bit 2 = sync incoming',
297 profilesync tinyint not null default 1 comment 'profile synchronization, bit 1 = sync outgoing, bit 2 = sync incoming',
298 last_noticesync datetime default null comment 'last time notices were imported',
299 last_friendsync datetime default null comment 'last time friends were imported',
300 created datetime not null comment 'date this record was created',
301 modified timestamp comment 'date this record was modified',
303 constraint primary key (user_id, foreign_id, service),
304 index foreign_user_user_id_idx (user_id)
305 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
307 create table foreign_subscription (
308 service int not null comment 'service where relationship happens' references foreign_service(id),
309 subscriber int not null comment 'subscriber on foreign service' references foreign_user (id),
310 subscribed int not null comment 'subscribed user' references foreign_user (id),
311 created datetime not null comment 'date this record was created',
313 constraint primary key (service, subscriber, subscribed),
314 index foreign_subscription_subscriber_idx (subscriber),
315 index foreign_subscription_subscribed_idx (subscribed)
316 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
318 create table invitation (
319 code varchar(32) not null primary key comment 'random code for an invitation',
320 user_id int not null comment 'who sent the invitation' references user (id),
321 address varchar(255) not null comment 'invitation sent to',
322 address_type varchar(8) not null comment 'address type ("email", "jabber", "sms")',
323 created datetime not null comment 'date this record was created',
325 index invitation_address_idx (address, address_type),
326 index invitation_user_id_idx (user_id)
327 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
329 create table message (
330 id integer auto_increment primary key comment 'unique identifier',
331 uri varchar(255) unique key comment 'universally unique identifier',
332 from_profile integer not null comment 'who the message is from' references profile (id),
333 to_profile integer not null comment 'who the message is to' references profile (id),
334 content text comment 'message content',
335 rendered text comment 'HTML version of the content',
336 url varchar(255) comment 'URL of any attachment (image, video, bookmark, whatever)',
337 created datetime not null comment 'date this record was created',
338 modified timestamp comment 'date this record was modified',
339 source varchar(32) comment 'source of comment, like "web", "im", or "clientname"',
341 index message_from_idx (from_profile),
342 index message_to_idx (to_profile),
343 index message_created_idx (created)
344 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_general_ci;
346 create table notice_inbox (
347 user_id integer not null comment 'user receiving the message' references user (id),
348 notice_id integer not null comment 'notice received' references notice (id),
349 created datetime not null comment 'date the notice was created',
350 source tinyint default 1 comment 'reason it is in the inbox, 1=subscription',
352 constraint primary key (user_id, notice_id),
353 index notice_inbox_notice_id_idx (notice_id)
354 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
356 create table profile_tag (
357 tagger integer not null comment 'user making the tag' references user (id),
358 tagged integer not null comment 'profile tagged' references profile (id),
359 tag varchar(64) not null comment 'hash tag associated with this notice',
360 modified timestamp comment 'date the tag was added',
362 constraint primary key (tagger, tagged, tag),
363 index profile_tag_modified_idx (modified),
364 index profile_tag_tagger_tag_idx (tagger, tag),
365 index profile_tag_tagged_idx (tagged)
366 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
368 create table profile_block (
369 blocker integer not null comment 'user making the block' references user (id),
370 blocked integer not null comment 'profile that is blocked' references profile (id),
371 modified timestamp comment 'date of blocking',
373 constraint primary key (blocker, blocked)
375 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
377 create table user_group (
378 id integer auto_increment primary key comment 'unique identifier',
380 nickname varchar(64) unique key comment 'nickname for addressing',
381 fullname varchar(255) comment 'display name',
382 homepage varchar(255) comment 'URL, cached so we dont regenerate',
383 description text comment 'group description',
384 location varchar(255) comment 'related physical location, if any',
386 original_logo varchar(255) comment 'original size logo',
387 homepage_logo varchar(255) comment 'homepage (profile) size logo',
388 stream_logo varchar(255) comment 'stream-sized logo',
389 mini_logo varchar(255) comment 'mini logo',
390 design_id integer comment 'id of a design' references design(id),
392 created datetime not null comment 'date this record was created',
393 modified timestamp comment 'date this record was modified',
395 index user_group_nickname_idx (nickname)
397 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_general_ci;
399 create table group_member (
400 group_id integer not null comment 'foreign key to user_group' references user_group (id),
401 profile_id integer not null comment 'foreign key to profile table' references profile (id),
402 is_admin boolean default false comment 'is this user an admin?',
404 created datetime not null comment 'date this record was created',
405 modified timestamp comment 'date this record was modified',
407 constraint primary key (group_id, profile_id),
408 index group_member_profile_id_idx (profile_id),
409 index group_member_created_idx (created)
411 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
413 create table related_group (
414 group_id integer not null comment 'foreign key to user_group' references user_group (id),
415 related_group_id integer not null comment 'foreign key to user_group' references user_group (id),
417 created datetime not null comment 'date this record was created',
419 constraint primary key (group_id, related_group_id)
421 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
423 create table group_inbox (
424 group_id integer not null comment 'group receiving the message' references user_group (id),
425 notice_id integer not null comment 'notice received' references notice (id),
426 created datetime not null comment 'date the notice was created',
428 constraint primary key (group_id, notice_id),
429 index group_inbox_created_idx (created)
431 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
435 id integer primary key auto_increment,
436 url varchar(255) comment 'destination URL after following redirections',
437 mimetype varchar(50) comment 'mime type of resource',
438 size integer comment 'size of resource when available',
439 title varchar(255) comment 'title of resource when available',
440 date integer(11) comment 'date of resource according to http query',
441 protected integer(1) comment 'true when URL is private (needs login)',
442 filename varchar(255) comment 'if a local file, name of the file',
444 modified timestamp comment 'date this record was modified',
447 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_general_ci;
449 create table file_oembed (
450 file_id integer primary key comment 'oEmbed for that URL/file' references file (id),
451 version varchar(20) comment 'oEmbed spec. version',
452 type varchar(20) comment 'oEmbed type: photo, video, link, rich',
453 mimetype varchar(50) comment 'mime type of resource',
454 provider varchar(50) comment 'name of this oEmbed provider',
455 provider_url varchar(255) comment 'URL of this oEmbed provider',
456 width integer comment 'width of oEmbed resource when available',
457 height integer comment 'height of oEmbed resource when available',
458 html text comment 'html representation of this oEmbed resource when applicable',
459 title varchar(255) comment 'title of oEmbed resource when available',
460 author_name varchar(50) comment 'author name for this oEmbed resource',
461 author_url varchar(255) comment 'author URL for this oEmbed resource',
462 url varchar(255) comment 'URL for this oEmbed resource when applicable (photo, link)',
463 modified timestamp comment 'date this record was modified'
465 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_general_ci;
467 create table file_redirection (
469 url varchar(255) primary key comment 'short URL (or any other kind of redirect) for file (id)',
470 file_id integer comment 'short URL for what URL/file' references file (id),
471 redirections integer comment 'redirect count',
472 httpcode integer comment 'HTTP status code (20x, 30x, etc.)',
473 modified timestamp comment 'date this record was modified'
475 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
477 create table file_thumbnail (
479 file_id integer primary key comment 'thumbnail for what URL/file' references file (id),
480 url varchar(255) comment 'URL of thumbnail',
481 width integer comment 'width of thumbnail',
482 height integer comment 'height of thumbnail',
483 modified timestamp comment 'date this record was modified',
486 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
488 create table file_to_post (
490 file_id integer comment 'id of URL/file' references file (id),
491 post_id integer comment 'id of the notice it belongs to' references notice (id),
492 modified timestamp comment 'date this record was modified',
494 constraint primary key (file_id, post_id)
496 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
498 create table design (
499 id integer primary key auto_increment comment 'design ID',
500 backgroundcolor integer comment 'main background color',
501 contentcolor integer comment 'content area background color',
502 sidebarcolor integer comment 'sidebar background color',
503 textcolor integer comment 'text color',
504 linkcolor integer comment 'link color',
505 backgroundimage varchar(255) comment 'background image, if any',
506 disposition tinyint default 1 comment 'bit 1 = hide background image, bit 2 = display background image, bit 4 = tile background image'
507 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
509 create table group_block (
510 group_id integer not null comment 'group profile is blocked from' references user_group (id),
511 blocked integer not null comment 'profile that is blocked' references profile (id),
512 blocker integer not null comment 'user making the block' references user (id),
513 modified timestamp comment 'date of blocking',
515 constraint primary key (group_id, blocked)
517 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
519 create table group_alias (
521 alias varchar(64) primary key comment 'additional nickname for the group',
522 group_id integer not null comment 'group profile is blocked from' references user_group (id),
523 modified timestamp comment 'date alias was created',
525 index group_alias_group_id_idx (group_id)
527 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
529 create table session (
531 id varchar(32) primary key comment 'session ID',
532 session_data text comment 'session data',
533 created datetime not null comment 'date this record was created',
534 modified timestamp comment 'date this record was modified',
536 index session_modified_idx (modified)
538 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
540 create table deleted_notice (
542 id integer primary key comment 'identity of notice',
543 profile_id integer not null comment 'author of the notice',
544 uri varchar(255) unique key comment 'universally unique identifier, usually a tag URI',
545 created datetime not null comment 'date the notice record was created',
546 deleted datetime not null comment 'date the notice record was created',
548 index deleted_notice_profile_id_idx (profile_id)
550 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
552 create table config (
554 section varchar(32) comment 'configuration section',
555 setting varchar(32) comment 'configuration setting',
556 value varchar(255) comment 'configuration value',
558 constraint primary key (section, setting)
560 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
562 create table profile_role (
564 profile_id integer not null comment 'account having the role' references profile (id),
565 role varchar(32) not null comment 'string representing the role',
566 created datetime not null comment 'date the role was granted',
568 constraint primary key (profile_id, role)
570 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
572 create table location_namespace (
574 id integer primary key comment 'identity for this namespace',
575 description varchar(255) comment 'description of the namespace',
576 created datetime not null comment 'date the record was created',
577 modified timestamp comment 'date this record was modified'
579 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;
581 create table login_token (
582 user_id integer not null comment 'user owning this token' references user (id),
583 token char(32) not null comment 'token useable for logging in',
584 created datetime not null comment 'date this record was created',
585 modified timestamp comment 'date this record was modified',
587 constraint primary key (user_id)
588 ) ENGINE=InnoDB CHARACTER SET utf8 COLLATE utf8_bin;