1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
|
CREATE DATABASE dumpfm;
CREATE TABLE users (
user_id SERIAL PRIMARY KEY,
nick text UNIQUE NOT NULL,
hash text NOT NULL,
email text NOT NULL,
created_on timestamp NOT NULL DEFAULT now(),
is_admin boolean NOT NULL DEFAULT false,
avatar text NOT NULL DEFAULT '',
contact text NOT NULL DEFAULT '',
bio text NOT NULL DEFAULT '',
profile_bg text
);
CREATE INDEX users_nick_lowercase_idx ON users (lower(nick));
CREATE TABLE rooms (
room_id SERIAL PRIMARY KEY,
key text UNIQUE NOT NULL,
name text NOT NULL,
description text NOT NULL,
created_on timestamp NOT NULL DEFAULT now(),
admin_only bool NOT NULL DEFAULT false
);
CREATE TABLE messages (
message_id SERIAL PRIMARY KEY,
user_id integer NOT NULL REFERENCES users,
room_id integer NOT NULL REFERENCES rooms,
content text NOT NULL,
created_on timestamp NOT NULL DEFAULT now(),
is_image bool NOT NULL
);
CREATE INDEX messages_user_id_idx ON messages (user_id);
CREATE INDEX messages_room_id_idx ON messages (room_id);
CREATE INDEX messages_created_on_idx ON messages (created_on);
CREATE INDEX messages_is_image_idx ON messages (is_image);
-- Queries to support:
-- 1) What messages are tagged x? (ordered by time, popularity)
-- 2) What did I tag x?
-- 3) Which of my things are tagged x?
-- 4) Which of user u's messages are tagged x?
-- 5) What are the popular tags lately?
CREATE TABLE tags (
user_id integer NOT NULL REFERENCES users,
message_id integer NOT NULL REFERENCES messages,
created_on timestamp NOT NULL DEFAULT now(),
tag text NOT NULL,
PRIMARY KEY (user_id, message_id, tag)
);
CREATE INDEX tags_user_id_idx ON tags (user_id);
CREATE INDEX tags_message_id_idx ON tags (message_id);
CREATE INDEX tags_created_on_id_idx ON tags (created_on DESC);
CREATE INDEX tags_tag_lowercase_idx ON tags (lower(tag));
CREATE TABLE mutes (
mute_id SERIAL PRIMARY KEY,
user_id integer NOT NULL REFERENCES users,
admin_id integer NOT NULL REFERENCES users,
set_on timestamp NOT NULL DEFAULT now(),
duration interval NOT NULL,
reason text NOT NULL,
cancelled bool NOT NULL DEFAULT false,
cancel_admin_id integer REFERENCES users,
cancel_reason text
);
CREATE INDEX mutes_expires_idx ON mutes ((set_on + duration));
INSERT INTO rooms (key, name, description, admin_only)
VALUES ('dumpfm', 'Room A', 'Hangout', false);
INSERT INTO rooms (key, name, description, admin_only)
VALUES ('VIP', 'The VIP Room', 'Command Post', true);
|