Skip to content

Commit 35eee5f

Browse files
author
Kaitlyn Parkhurst
committed
Create Schema.
0 parents  commit 35eee5f

File tree

1 file changed

+130
-0
lines changed

1 file changed

+130
-0
lines changed

DB/etc/schema.sql

Lines changed: 130 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,130 @@
1+
CREATE EXTENSION IF NOT EXISTS citext;
2+
3+
CREATE TABLE person (
4+
id serial PRIMARY KEY,
5+
username citext not null unique,
6+
email citext not null unique,
7+
tagline text ,
8+
about text ,
9+
is_enabled boolean not null default true,
10+
created_at timestamptz not null default current_timestamp
11+
);
12+
13+
-- Settings for a given user.
14+
create TABLE person_settings (
15+
id serial PRIMARY KEY,
16+
person_id int not null references person(id),
17+
name text not null,
18+
value json not null default '{}',
19+
created_at timestamptz not null default current_timestamp,
20+
21+
-- Allow ->find_or_new_related()
22+
CONSTRAINT unq_person_id_name UNIQUE(person_id, name)
23+
);
24+
25+
-- A password can be associated with a user account.
26+
CREATE TABLE auth_password (
27+
person_id int not null unique references person(id),
28+
password text not null,
29+
salt text not null,
30+
updated_at timestamptz not null default current_timestamp,
31+
created_at timestamptz not null default current_timestamp
32+
);
33+
34+
-- Reset passwords by creating a token for the user. Tokens can only be used
35+
-- once and should be marked is_redeemed true after use.
36+
CREATE TABLE password_token (
37+
id serial PRIMARY KEY,
38+
person_id int not null references person(id),
39+
token text not null,
40+
is_redeemed boolean not null default false,
41+
created_at timestamptz not null default current_timestamp
42+
);
43+
44+
-- Root table for the blog listing.
45+
CREATE TABLE blog (
46+
id serial PRIMARY KEY,
47+
url text not null unique,
48+
img_url text ,
49+
rss_url text ,
50+
title text ,
51+
tagline text ,
52+
about text ,
53+
last_updated timestamptz ,
54+
is_published boolean not null default true,
55+
is_adult boolean not null default false,
56+
created_at timestamptz not null default current_timestamp
57+
);
58+
59+
-- RSS Reader will create these for the blogs.
60+
CREATE TABLE blog_entry (
61+
id serial PRIMARY KEY,
62+
blog_id int not null references blog(id),
63+
title text not null,
64+
url text not null,
65+
publish_date timestamptz not null,
66+
description text ,
67+
created_at timestamptz not null default current_timestamp
68+
);
69+
70+
-- Tags that are approved.
71+
CREATE TABLE tag (
72+
id serial PRIMARY KEY,
73+
name text not null unique,
74+
is_adult boolean not null default false,
75+
created_at timestamptz not null default current_timestamp
76+
);
77+
78+
-- Map between tags <-> blogs so we can get a listing of tags for a blog, or a listing
79+
-- of blogs for a tag.
80+
CREATE TABLE blog_tag_map (
81+
id serial PRIMARY KEY,
82+
blog_id int not null references blog(id),
83+
tag_id int not null references tag(id),
84+
created_at timestamptz not null default current_timestamp
85+
);
86+
87+
-- When a user adds a tag, it's added to the pending table, and can be voted on,
88+
-- approved, or deleted.
89+
CREATE TABLE pending_tag (
90+
id serial PRIMARY KEY,
91+
name text not null unique,
92+
created_at timestamptz not null default current_timestamp
93+
);
94+
95+
-- Normal users can vote on tags, vote will be 1 or -1
96+
CREATE TABLE tag_vote (
97+
id serial PRIMARY KEY,
98+
tag_id int not null references pending_tag(id),
99+
person_id int not null references person(id),
100+
vote int not null default '1',
101+
created_at timestamptz not null default current_timestamp
102+
);
103+
104+
-- Allow people to follow blogs, and make a people <-> blog association.
105+
CREATE TABLE person_follow_blog_map (
106+
id serial PRIMARY KEY,
107+
person_id int not null references person(id),
108+
blog_id int not null references blog(id),
109+
created_at timestamptz not null default current_timestamp
110+
);
111+
112+
-- Allow people to follow other people, and make a people <-> followed association.
113+
CREATE TABLE person_follow_person_map (
114+
id serial PRIMARY KEY,
115+
person_id int not null references person(id),
116+
follow_id int not null references person(id),
117+
created_at timestamptz not null default current_timestamp
118+
);
119+
120+
-- Message thread for blogs.
121+
CREATE TABLE message (
122+
id serial PRIMARY KEY,
123+
author_id int not null references person(id),
124+
blog_id int references blog(id), -- Find all root comments for blog
125+
parent_id int references message(id), -- Find children for recursive messages
126+
vote int not null default '1', -- Does the user recommend the blog?
127+
content text ,
128+
created_at timestamptz not null default current_timestamp
129+
);
130+

0 commit comments

Comments
 (0)