--- /dev/null
+/* local and remote users have profiles */\r
+\r
+create table profile (\r
+ id serial primary key /* comment 'unique identifier' */,\r
+ nickname varchar(64) not null /* comment 'nickname or username' */,\r
+ fullname varchar(255) /* comment 'display name' */,\r
+ profileurl varchar(255) /* comment 'URL, cached so we dont regenerate' */,\r
+ homepage varchar(255) /* comment 'identifying URL' */,\r
+ bio varchar(140) /* comment 'descriptive biography' */,\r
+ location varchar(255) /* comment 'physical location' */,\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+ modified timestamp /* comment 'date this record was modified' */\r
+\r
+/* FULLTEXT(nickname, fullname, location, bio, homepage) */\r
+);\r
+create index profile_nickname_idx on profile using btree(nickname);\r
+\r
+\r
+\r
+create table avatar (\r
+ profile_id integer not null /* comment 'foreign key to profile table' */ references profile (id) ,\r
+ original integer default 0 /* comment 'uploaded by user or generated?' */,\r
+ width integer not null /* comment 'image width' */,\r
+ height integer not null /* comment 'image height' */,\r
+ mediatype varchar(32) not null /* comment 'file type' */,\r
+ filename varchar(255) null /* comment 'local filename, if local' */,\r
+ url varchar(255) unique /* comment 'avatar location' */,\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+ modified timestamp /* comment 'date this record was modified' */,\r
+\r
+ primary key(profile_id, width, height)\r
+);\r
+create index avatar_profile_id_idx on avatar using btree(profile_id);\r
+\r
+create table sms_carrier (\r
+ id serial primary key /* comment 'primary key for SMS carrier' */,\r
+ name varchar(64) unique /* comment 'name of the carrier' */,\r
+ email_pattern varchar(255) not null /* comment 'sprintf pattern for making an email address from a phone number' */,\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+ modified timestamp /* comment 'date this record was modified ' */\r
+);\r
+\r
+/* local users */\r
+\r
+create table "user" (\r
+ id integer primary key /* comment 'foreign key to profile table' */ references profile (id) ,\r
+ nickname varchar(64) unique /* comment 'nickname or username, duped in profile' */,\r
+ password varchar(255) /* comment 'salted password, can be null for OpenID users' */,\r
+ email varchar(255) unique /* comment 'email address for password recovery etc.' */,\r
+ incomingemail varchar(255) unique /* comment 'email address for post-by-email' */,\r
+ emailnotifysub integer default 1 /* comment 'Notify by email of subscriptions' */,\r
+ emailmicroid integer default 1 /* comment 'whether to publish email microid' */,\r
+ language varchar(50) /* comment 'preferred language' */,\r
+ timezone varchar(50) /* comment 'timezone' */,\r
+ emailpost integer default 1 /* comment 'Post by email' */,\r
+ jabber varchar(255) unique /* comment 'jabber ID for notices' */,\r
+ jabbernotify integer default 0 /* comment 'whether to send notices to jabber' */,\r
+ jabberreplies integer default 0 /* comment 'whether to send notices to jabber on replies' */,\r
+ jabbermicroid integer default 1 /* comment 'whether to publish xmpp microid' */,\r
+ updatefrompresence integer default 0 /* comment 'whether to record updates from Jabber presence notices' */,\r
+ sms varchar(64) unique /* comment 'sms phone number' */,\r
+ carrier integer /* comment 'foreign key to sms_carrier' */ references sms_carrier (id) ,\r
+ smsnotify integer default 0 /* comment 'whether to send notices to SMS' */,\r
+ smsreplies integer default 0 /* comment 'whether to send notices to SMS on replies' */,\r
+ smsemail varchar(255) /* comment 'built from sms and carrier' */,\r
+ uri varchar(255) unique /* comment 'universally unique identifier, usually a tag URI' */,\r
+ autosubscribe integer default 0 /* comment 'automatically subscribe to users who subscribe to us' */,\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+ modified timestamp /* comment 'date this record was modified' */\r
+\r
+);\r
+create index user_smsemail_idx on "user" using btree(smsemail);\r
+\r
+/* remote people */\r
+\r
+create table remote_profile (\r
+ id integer primary key /* comment 'foreign key to profile table' */ references profile (id) ,\r
+ uri varchar(255) unique /* comment 'universally unique identifier, usually a tag URI' */,\r
+ postnoticeurl varchar(255) /* comment 'URL we use for posting notices' */,\r
+ updateprofileurl varchar(255) /* comment 'URL we use for updates to this profile' */,\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+ modified timestamp /* comment 'date this record was modified' */\r
+);\r
+\r
+create table subscription (\r
+ subscriber integer not null /* comment 'profile listening' */,\r
+ subscribed integer not null /* comment 'profile being listened to' */,\r
+ token varchar(255) /* comment 'authorization token' */,\r
+ secret varchar(255) /* comment 'token secret' */,\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+ modified timestamp /* comment 'date this record was modified' */,\r
+\r
+ primary key (subscriber, subscribed)\r
+);\r
+create index subscription_subscriber_idx on subscription using btree(subscriber);\r
+create index subscription_subscribed_idx on subscription using btree(subscribed);\r
+\r
+create table notice (\r
+\r
+ id serial primary key /* comment 'unique identifier' */,\r
+ profile_id integer not null /* comment 'who made the update' */ references profile (id) ,\r
+ uri varchar(255) unique /* comment 'universally unique identifier, usually a tag URI' */,\r
+ content varchar(140) /* comment 'update content' */,\r
+ rendered text /* comment 'HTML version of the content' */,\r
+ url varchar(255) /* comment 'URL of any attachment (image, video, bookmark, whatever)' */,\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+ modified timestamp /* comment 'date this record was modified' */,\r
+ reply_to integer /* comment 'notice replied to (usually a guess)' */ references notice (id) ,\r
+ is_local integer default 0 /* comment 'notice was generated by a user' */,\r
+ source varchar(32) /* comment 'source of comment, like "web", "im", or "clientname"' */\r
+\r
+/* FULLTEXT(content) */\r
+);\r
+create index notice_profile_id_idx on notice using btree(profile_id);\r
+create index notice_created_idx on notice using btree(created);\r
+\r
+create table notice_source (\r
+ code varchar(32) primary key not null /* comment 'source code' */,\r
+ name varchar(255) not null /* comment 'name of the source' */,\r
+ url varchar(255) not null /* comment 'url to link to' */,\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+ modified timestamp /* comment 'date this record was modified' */\r
+);\r
+\r
+create table reply (\r
+\r
+ notice_id integer not null /* comment 'notice that is the reply' */ references notice (id) ,\r
+ profile_id integer not null /* comment 'profile replied to' */ references profile (id) ,\r
+ modified timestamp not null /* comment 'date this record was modified' */,\r
+ replied_id integer /* comment 'notice replied to (not used, see notice.reply_to)' */,\r
+\r
+ primary key (notice_id, profile_id)\r
+\r
+);\r
+create index reply_notice_id_idx on reply using btree(notice_id);\r
+create index reply_profile_id_idx on reply using btree(profile_id);\r
+create index reply_replied_id_idx on reply using btree(replied_id);\r
+\r
+create table fave (\r
+\r
+ notice_id integer not null /* comment 'notice that is the favorite' */ references notice (id),\r
+ user_id integer not null /* comment 'user who likes this notice' */ references "user" (id) ,\r
+ modified timestamp not null /* comment 'date this record was modified' */,\r
+\r
+ primary key (notice_id, user_id)\r
+\r
+);\r
+create index fave_notice_id_idx on fave using btree(notice_id);\r
+create index fave_user_id_idx on fave using btree(user_id);\r
+create index fave_modified_idx on fave using btree(modified);\r
+\r
+/* tables for OAuth */\r
+\r
+create table consumer (\r
+ consumer_key varchar(255) primary key /* comment 'unique identifier, root URL' */,\r
+ seed char(32) not null /* comment 'seed for new tokens by this consumer' */,\r
+\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+ modified timestamp /* comment 'date this record was modified' */\r
+);\r
+\r
+create table token (\r
+ consumer_key varchar(255) not null /* comment 'unique identifier, root URL' */ references consumer (consumer_key),\r
+ tok char(32) not null /* comment 'identifying value' */,\r
+ secret char(32) not null /* comment 'secret value' */,\r
+ type integer not null default 0 /* comment 'request or access' */,\r
+ state integer default 0 /* comment 'for requests; 0 = initial, 1 = authorized, 2 = used' */,\r
+\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+ modified timestamp /* comment 'date this record was modified' */,\r
+\r
+ primary key (consumer_key, tok)\r
+);\r
+\r
+create table nonce (\r
+ consumer_key varchar(255) not null /* comment 'unique identifier, root URL' */,\r
+ tok char(32) not null /* comment 'identifying value' */,\r
+ nonce char(32) not null /* comment 'nonce' */,\r
+ ts timestamp not null /* comment 'timestamp sent' */,\r
+\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+ modified timestamp /* comment 'date this record was modified' */,\r
+\r
+ primary key (consumer_key, tok, nonce),\r
+ foreign key (consumer_key, tok) references token (consumer_key, tok)\r
+);\r
+\r
+/* One-to-many relationship of user to openid_url */\r
+\r
+create table user_openid (\r
+ canonical varchar(255) primary key /* comment 'Canonical true URL' */,\r
+ display varchar(255) not null unique /* comment 'URL for viewing, may be different from canonical' */,\r
+ user_id integer not null /* comment 'user owning this URL' */ references "user" (id) ,\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+ modified timestamp /* comment 'date this record was modified' */\r
+\r
+);\r
+create index user_openid_user_id_idx on user_openid using btree(user_id);\r
+\r
+/* These are used by JanRain OpenID library */\r
+\r
+create table oid_associations (\r
+ server_url varchar(2047),\r
+ handle varchar(255),\r
+ secret bytea,\r
+ issued integer,\r
+ lifetime integer,\r
+ assoc_type varchar(64),\r
+ primary key (server_url, handle)\r
+);\r
+\r
+create table oid_nonces (\r
+ server_url varchar(2047),\r
+ "timestamp" integer,\r
+ salt character(40),\r
+ unique (server_url, "timestamp", salt)\r
+);\r
+\r
+create table confirm_address (\r
+ code varchar(32) not null primary key /* comment 'good random code' */,\r
+ user_id integer not null /* comment 'user who requested confirmation' */ references "user" (id),\r
+ address varchar(255) not null /* comment 'address (email, Jabber, SMS, etc.)' */,\r
+ address_extra varchar(255) not null /* comment 'carrier ID, for SMS' */,\r
+ address_type varchar(8) not null /* comment 'address type ("email", "jabber", "sms")' */,\r
+ claimed timestamp /* comment 'date this was claimed for queueing' */,\r
+ sent timestamp /* comment 'date this was sent for queueing' */,\r
+ modified timestamp /* comment 'date this record was modified' */\r
+);\r
+\r
+create table remember_me (\r
+ code varchar(32) not null primary key /* comment 'good random code' */,\r
+ user_id integer not null /* comment 'user who is logged in' */ references "user" (id),\r
+ modified timestamp /* comment 'date this record was modified' */\r
+);\r
+\r
+create table queue_item (\r
+\r
+ notice_id integer not null /* comment 'notice queued' */ references notice (id) ,\r
+ transport varchar(8) not null /* comment 'queue for what? "email", "jabber", "sms", "irc", ...' */,\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+ claimed timestamp /* comment 'date this item was claimed' */,\r
+\r
+ primary key (notice_id, transport)\r
+\r
+);\r
+create index queue_item_created_idx on queue_item using btree(created);\r
+\r
+/* Hash tags */\r
+create table notice_tag (\r
+ tag varchar( 64 ) not null /* comment 'hash tag associated with this notice' */,\r
+ notice_id integer not null /* comment 'notice tagged' */ references notice (id) ,\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+\r
+ primary key (tag, notice_id)\r
+);\r
+create index notice_tag_created_idx on notice_tag using btree(created);\r
+\r
+/* Synching with foreign services */\r
+\r
+create table foreign_service (\r
+ id int not null primary key /* comment 'numeric key for service' */,\r
+ name varchar(32) not null unique /* comment 'name of the service' */,\r
+ description varchar(255) /* comment 'description' */,\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+ modified timestamp /* comment 'date this record was modified' */\r
+);\r
+\r
+create table foreign_user (\r
+ id int not null /* comment 'unique numeric key on foreign service' */,\r
+ service int not null /* comment 'foreign key to service' */ references foreign_service(id) ,\r
+ uri varchar(255) not null unique /* comment 'identifying URI' */,\r
+ nickname varchar(255) /* comment 'nickname on foreign service' */,\r
+ user_id int /* comment 'link to user on this system, if exists' */ references "user" (id), \r
+ credentials varchar(255) /* comment 'authc credentials, typically a password' */,\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+ modified timestamp /* comment 'date this record was modified' */,\r
+ \r
+ primary key (id, service)\r
+);\r
+create index foreign_user_user_id_idx on foreign_user using btree(user_id);\r
+\r
+create table foreign_subscription (\r
+ service int not null /* comment 'service where relationship happens' */ references foreign_service(id) ,\r
+ subscriber int not null /* comment 'subscriber on foreign service' */ ,\r
+ subscribed int not null /* comment 'subscribed user' */ ,\r
+ created timestamp not null /* comment 'date this record was created' */,\r
+ \r
+ primary key (service, subscriber, subscribed)\r
+);\r
+create index foreign_subscription_subscriber_idx on foreign_subscription using btree(subscriber);\r
+create index foreign_subscription_subscribed_idx on foreign_subscription using btree(subscribed);\r