1 /* local and remote users have profiles */
\r
3 create table profile (
\r
4 id serial primary key /* comment 'unique identifier' */,
\r
5 nickname varchar(64) not null /* comment 'nickname or username' */,
\r
6 fullname varchar(255) /* comment 'display name' */,
\r
7 profileurl varchar(255) /* comment 'URL, cached so we dont regenerate' */,
\r
8 homepage varchar(255) /* comment 'identifying URL' */,
\r
9 bio varchar(140) /* comment 'descriptive biography' */,
\r
10 location varchar(255) /* comment 'physical location' */,
\r
11 created timestamp not null /* comment 'date this record was created' */,
\r
12 modified timestamp /* comment 'date this record was modified' */,
\r
16 create index profile_nickname_idx on profile using btree(nickname);
\r
18 create table avatar (
\r
19 profile_id integer not null /* comment 'foreign key to profile table' */ references profile (id) ,
\r
20 original integer default 0 /* comment 'uploaded by user or generated?' */,
\r
21 width integer not null /* comment 'image width' */,
\r
22 height integer not null /* comment 'image height' */,
\r
23 mediatype varchar(32) not null /* comment 'file type' */,
\r
24 filename varchar(255) null /* comment 'local filename, if local' */,
\r
25 url varchar(255) unique /* comment 'avatar location' */,
\r
26 created timestamp not null /* comment 'date this record was created' */,
\r
27 modified timestamp /* comment 'date this record was modified' */,
\r
29 primary key(profile_id, width, height)
\r
31 create index avatar_profile_id_idx on avatar using btree(profile_id);
\r
33 create table sms_carrier (
\r
34 id serial primary key /* comment 'primary key for SMS carrier' */,
\r
35 name varchar(64) unique /* comment 'name of the carrier' */,
\r
36 email_pattern varchar(255) not null /* comment 'sprintf pattern for making an email address from a phone number' */,
\r
37 created timestamp not null /* comment 'date this record was created' */,
\r
38 modified timestamp /* comment 'date this record was modified ' */
\r
43 create table "user" (
\r
44 id integer primary key /* comment 'foreign key to profile table' */ references profile (id) ,
\r
45 nickname varchar(64) unique /* comment 'nickname or username, duped in profile' */,
\r
46 password varchar(255) /* comment 'salted password, can be null for OpenID users' */,
\r
47 email varchar(255) unique /* comment 'email address for password recovery etc.' */,
\r
48 incomingemail varchar(255) unique /* comment 'email address for post-by-email' */,
\r
49 emailnotifysub integer default 1 /* comment 'Notify by email of subscriptions' */,
\r
50 emailmicroid integer default 1 /* comment 'whether to publish email microid' */,
\r
51 language varchar(50) /* comment 'preferred language' */,
\r
52 timezone varchar(50) /* comment 'timezone' */,
\r
53 emailpost integer default 1 /* comment 'Post by email' */,
\r
54 jabber varchar(255) unique /* comment 'jabber ID for notices' */,
\r
55 jabbernotify integer default 0 /* comment 'whether to send notices to jabber' */,
\r
56 jabberreplies integer default 0 /* comment 'whether to send notices to jabber on replies' */,
\r
57 jabbermicroid integer default 1 /* comment 'whether to publish xmpp microid' */,
\r
58 updatefrompresence integer default 0 /* comment 'whether to record updates from Jabber presence notices' */,
\r
59 sms varchar(64) unique /* comment 'sms phone number' */,
\r
60 carrier integer /* comment 'foreign key to sms_carrier' */ references sms_carrier (id) ,
\r
61 smsnotify integer default 0 /* comment 'whether to send notices to SMS' */,
\r
62 smsreplies integer default 0 /* comment 'whether to send notices to SMS on replies' */,
\r
63 smsemail varchar(255) /* comment 'built from sms and carrier' */,
\r
64 uri varchar(255) unique /* comment 'universally unique identifier, usually a tag URI' */,
\r
65 autosubscribe integer default 0 /* comment 'automatically subscribe to users who subscribe to us' */,
\r
66 created timestamp not null /* comment 'date this record was created' */,
\r
67 modified timestamp /* comment 'date this record was modified' */
\r
70 create index user_smsemail_idx on "user" using btree(smsemail);
\r
74 create table remote_profile (
\r
75 id integer primary key /* comment 'foreign key to profile table' */ references profile (id) ,
\r
76 uri varchar(255) unique /* comment 'universally unique identifier, usually a tag URI' */,
\r
77 postnoticeurl varchar(255) /* comment 'URL we use for posting notices' */,
\r
78 updateprofileurl varchar(255) /* comment 'URL we use for updates to this profile' */,
\r
79 created timestamp not null /* comment 'date this record was created' */,
\r
80 modified timestamp /* comment 'date this record was modified' */
\r
83 create table subscription (
\r
84 subscriber integer not null /* comment 'profile listening' */,
\r
85 subscribed integer not null /* comment 'profile being listened to' */,
\r
86 token varchar(255) /* comment 'authorization token' */,
\r
87 secret varchar(255) /* comment 'token secret' */,
\r
88 created timestamp not null /* comment 'date this record was created' */,
\r
89 modified timestamp /* comment 'date this record was modified' */,
\r
91 primary key (subscriber, subscribed)
\r
93 create index subscription_subscriber_idx on subscription using btree(subscriber);
\r
94 create index subscription_subscribed_idx on subscription using btree(subscribed);
\r
96 create table notice (
\r
98 id serial primary key /* comment 'unique identifier' */,
\r
99 profile_id integer not null /* comment 'who made the update' */ references profile (id) ,
\r
100 uri varchar(255) unique /* comment 'universally unique identifier, usually a tag URI' */,
\r
101 content varchar(140) /* comment 'update content' */,
\r
102 rendered text /* comment 'HTML version of the content' */,
\r
103 url varchar(255) /* comment 'URL of any attachment (image, video, bookmark, whatever)' */,
\r
104 created timestamp not null /* comment 'date this record was created' */,
\r
105 modified timestamp /* comment 'date this record was modified' */,
\r
106 reply_to integer /* comment 'notice replied to (usually a guess)' */ references notice (id) ,
\r
107 is_local integer default 0 /* comment 'notice was generated by a user' */,
\r
108 source varchar(32) /* comment 'source of comment, like "web", "im", or "clientname"' */
\r
110 /* FULLTEXT(content) */
\r
112 create index notice_profile_id_idx on notice using btree(profile_id);
\r
113 create index notice_created_idx on notice using btree(created);
\r
115 create table notice_source (
\r
116 code varchar(32) primary key not null /* comment 'source code' */,
\r
117 name varchar(255) not null /* comment 'name of the source' */,
\r
118 url varchar(255) not null /* comment 'url to link to' */,
\r
119 created timestamp not null /* comment 'date this record was created' */,
\r
120 modified timestamp /* comment 'date this record was modified' */
\r
123 create table reply (
\r
125 notice_id integer not null /* comment 'notice that is the reply' */ references notice (id) ,
\r
126 profile_id integer not null /* comment 'profile replied to' */ references profile (id) ,
\r
127 modified timestamp not null default 'now' /* comment 'date this record was modified' */,
\r
128 replied_id integer /* comment 'notice replied to (not used, see notice.reply_to)' */,
\r
130 primary key (notice_id, profile_id)
\r
133 create index reply_notice_id_idx on reply using btree(notice_id);
\r
134 create index reply_profile_id_idx on reply using btree(profile_id);
\r
135 create index reply_replied_id_idx on reply using btree(replied_id);
\r
137 create table fave (
\r
139 notice_id integer not null /* comment 'notice that is the favorite' */ references notice (id),
\r
140 user_id integer not null /* comment 'user who likes this notice' */ references "user" (id) ,
\r
141 modified timestamp not null /* comment 'date this record was modified' */,
\r
143 primary key (notice_id, user_id)
\r
146 create index fave_notice_id_idx on fave using btree(notice_id);
\r
147 create index fave_user_id_idx on fave using btree(user_id);
\r
148 create index fave_modified_idx on fave using btree(modified);
\r
150 /* tables for OAuth */
\r
152 create table consumer (
\r
153 consumer_key varchar(255) primary key /* comment 'unique identifier, root URL' */,
\r
154 seed char(32) not null /* comment 'seed for new tokens by this consumer' */,
\r
156 created timestamp not null /* comment 'date this record was created' */,
\r
157 modified timestamp /* comment 'date this record was modified' */
\r
160 create table token (
\r
161 consumer_key varchar(255) not null /* comment 'unique identifier, root URL' */ references consumer (consumer_key),
\r
162 tok char(32) not null /* comment 'identifying value' */,
\r
163 secret char(32) not null /* comment 'secret value' */,
\r
164 type integer not null default 0 /* comment 'request or access' */,
\r
165 state integer default 0 /* comment 'for requests; 0 = initial, 1 = authorized, 2 = used' */,
\r
167 created timestamp not null /* comment 'date this record was created' */,
\r
168 modified timestamp /* comment 'date this record was modified' */,
\r
170 primary key (consumer_key, tok)
\r
173 create table nonce (
\r
174 consumer_key varchar(255) not null /* comment 'unique identifier, root URL' */,
\r
175 tok char(32) not null /* comment 'identifying value' */,
\r
176 nonce char(32) not null /* comment 'nonce' */,
\r
177 ts timestamp not null /* comment 'timestamp sent' */,
\r
179 created timestamp not null /* comment 'date this record was created' */,
\r
180 modified timestamp /* comment 'date this record was modified' */,
\r
182 primary key (consumer_key, tok, nonce),
\r
183 foreign key (consumer_key, tok) references token (consumer_key, tok)
\r
186 /* One-to-many relationship of user to openid_url */
\r
188 create table user_openid (
\r
189 canonical varchar(255) primary key /* comment 'Canonical true URL' */,
\r
190 display varchar(255) not null unique /* comment 'URL for viewing, may be different from canonical' */,
\r
191 user_id integer not null /* comment 'user owning this URL' */ references "user" (id) ,
\r
192 created timestamp not null /* comment 'date this record was created' */,
\r
193 modified timestamp /* comment 'date this record was modified' */
\r
196 create index user_openid_user_id_idx on user_openid using btree(user_id);
\r
198 /* These are used by JanRain OpenID library */
\r
200 create table oid_associations (
\r
201 server_url varchar(2047),
\r
202 handle varchar(255),
\r
206 assoc_type varchar(64),
\r
207 primary key (server_url, handle)
\r
210 create table oid_nonces (
\r
211 server_url varchar(2047),
\r
212 "timestamp" integer,
\r
213 salt character(40),
\r
214 unique (server_url, "timestamp", salt)
\r
217 create table confirm_address (
\r
218 code varchar(32) not null primary key /* comment 'good random code' */,
\r
219 user_id integer not null /* comment 'user who requested confirmation' */ references "user" (id),
\r
220 address varchar(255) not null /* comment 'address (email, Jabber, SMS, etc.)' */,
\r
221 address_extra varchar(255) not null /* comment 'carrier ID, for SMS' */,
\r
222 address_type varchar(8) not null /* comment 'address type ("email", "jabber", "sms")' */,
\r
223 claimed timestamp /* comment 'date this was claimed for queueing' */,
\r
224 sent timestamp /* comment 'date this was sent for queueing' */,
\r
225 modified timestamp /* comment 'date this record was modified' */
\r
228 create table remember_me (
\r
229 code varchar(32) not null primary key /* comment 'good random code' */,
\r
230 user_id integer not null /* comment 'user who is logged in' */ references "user" (id),
\r
231 modified timestamp /* comment 'date this record was modified' */
\r
234 create table queue_item (
\r
236 notice_id integer not null /* comment 'notice queued' */ references notice (id) ,
\r
237 transport varchar(8) not null /* comment 'queue for what? "email", "jabber", "sms", "irc", ...' */,
\r
238 created timestamp not null /* comment 'date this record was created' */,
\r
239 claimed timestamp /* comment 'date this item was claimed' */,
\r
241 primary key (notice_id, transport)
\r
244 create index queue_item_created_idx on queue_item using btree(created);
\r
247 create table notice_tag (
\r
248 tag varchar( 64 ) not null /* comment 'hash tag associated with this notice' */,
\r
249 notice_id integer not null /* comment 'notice tagged' */ references notice (id) ,
\r
250 created timestamp not null /* comment 'date this record was created' */,
\r
252 primary key (tag, notice_id)
\r
254 create index notice_tag_created_idx on notice_tag using btree(created);
\r
256 /* Synching with foreign services */
\r
258 create table foreign_service (
\r
259 id int not null primary key /* comment 'numeric key for service' */,
\r
260 name varchar(32) not null unique /* comment 'name of the service' */,
\r
261 description varchar(255) /* comment 'description' */,
\r
262 created timestamp not null /* comment 'date this record was created' */,
\r
263 modified timestamp /* comment 'date this record was modified' */
\r
266 create table foreign_user (
\r
267 id int not null /* comment 'unique numeric key on foreign service' */,
\r
268 service int not null /* comment 'foreign key to service' */ references foreign_service(id) ,
\r
269 uri varchar(255) not null unique /* comment 'identifying URI' */,
\r
270 nickname varchar(255) /* comment 'nickname on foreign service' */,
\r
271 user_id int /* comment 'link to user on this system, if exists' */ references "user" (id),
\r
272 credentials varchar(255) /* comment 'authc credentials, typically a password' */,
\r
273 created timestamp not null /* comment 'date this record was created' */,
\r
274 modified timestamp /* comment 'date this record was modified' */,
\r
276 primary key (id, service)
\r
278 create index foreign_user_user_id_idx on foreign_user using btree(user_id);
\r
280 create table foreign_subscription (
\r
281 service int not null /* comment 'service where relationship happens' */ references foreign_service(id) ,
\r
282 subscriber int not null /* comment 'subscriber on foreign service' */ ,
\r
283 subscribed int not null /* comment 'subscribed user' */ ,
\r
284 created timestamp not null /* comment 'date this record was created' */,
\r
286 primary key (service, subscriber, subscribed)
\r
288 create index foreign_subscription_subscriber_idx on foreign_subscription using btree(subscriber);
\r
289 create index foreign_subscription_subscribed_idx on foreign_subscription using btree(subscribed);
\r
291 /* Textsearch stuff */
\r
293 create index textsearch_idx on profile using gist(textsearch);
\r
294 create index noticecontent_idx on notice using gist(to_tsvector('english',content));
\r
295 create trigger textsearchupdate before insert or update on profile for each row
\r
296 execute procedure tsvector_update_trigger(textsearch, 'pg_catalog.english', nickname, fullname, location, bio, homepage);
\r