summaryrefslogtreecommitdiff
path: root/schema.sql
blob: 630479019d342cb18ac420a8dd3ead6342c2227f (plain)
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
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
BEGIN TRANSACTION;

-- For PostgreSQL 9.1 upward, we should consider using enum types
-- instead of VARCHARs with CHECK constraints:
--
-- CREATE TYPE user_status AS
--   ENUM ('pending', 'approved', 'trusted', 'deferred', 'disabled', 'admin');
--
-- CREATE TYPE comment_status AS
--   ENUM ('pending', 'approved', 'trusted', 'deferred', 'spam', 'rejected');
--
-- CREATE TYPE text_format AS
--   ENUM ('html', 'text');


CREATE TABLE users(
  id     SERIAL  NOT NULL,
  name   VARCHAR,
  status VARCHAR NOT NULL,
  PRIMARY KEY (id),
  CHECK (status IN ('pending', 'approved', 'trusted', 'deferred', 'disabled',
                    'admin'))
);

CREATE TABLE passwords(
  "user"   INTEGER NOT NULL,
  id       INTEGER NOT NULL,
  password VARCHAR NOT NULL,
  PRIMARY KEY ("user", id),
  FOREIGN KEY ("user") REFERENCES users
);  

CREATE TABLE openids(
  "user" INTEGER NOT NULL,
  id     INTEGER NOT NULL,
  openid VARCHAR NOT NULL,
  PRIMARY KEY ("user", id),
  FOREIGN KEY ("user") REFERENCES users
);  

CREATE TABLE login_certificates(
  "user"      INTEGER NOT NULL,
  id          INTEGER NOT NULL,
  certificate BYTEA NOT NULL,
  PRIMARY KEY ("user", id),
  FOREIGN KEY ("user") REFERENCES users
);

CREATE TABLE articles(
  id SERIAL NOT NULL,
  PRIMARY KEY (id)
);

CREATE TABLE article_aliases(
  alias   VARCHAR NOT NULL,
  article INTEGER NOT NULL,
  PRIMARY KEY (alias),
  FOREIGN KEY (article) REFERENCES articles
);

CREATE TABLE comments(
  id      SERIAL  NOT NULL,
  article INTEGER NOT NULL,
  PRIMARY KEY (id, article),
  FOREIGN KEY (article) REFERENCES articles
);

CREATE TABLE article_revisions(
  article   INTEGER   NOT NULL,
  id        INTEGER   NOT NULL,
  date      TIMESTAMP DEFAULT now(),
  title     VARCHAR   NOT NULL,
  content   VARCHAR   NOT NULL,
  author    INTEGER,
  format    varchar   NOT NULL,
  PRIMARY KEY (article, id),
  FOREIGN KEY (article) REFERENCES articles,
  FOREIGN KEY (author)  REFERENCES users,
  CHECK (format IN ('html'))
);

CREATE TABLE article_revision_characteristics(
  article        INTEGER NOT NULL,
  revision       INTEGER NOT NULL,
  characteristic VARCHAR NOT NULL,
  value          VARCHAR,
  FOREIGN KEY (article, revision) REFERENCES article_revisions
);

CREATE TABLE article_revision_parenthood(
  article   INTEGER NOT NULL,
  parent_id INTEGER NOT NULL,
  child_id  INTEGER NOT NULL,
  FOREIGN KEY (article, parent_id) REFERENCES article_revisions,
  FOREIGN KEY (article, child_id)  REFERENCES article_revisions
);

CREATE TABLE comment_revisions(
  article          INTEGER   NOT NULL,
  comment_id       INTEGER   NOT NULL,
  id               INTEGER   NOT NULL,
  date             TIMESTAMP DEFAULT now(),
  content          VARCHAR   NOT NULL,
  author           INTEGER,
  format           VARCHAR   NOT NULL,
  status           VARCHAR   NOT NULL,
  article_revision INTEGER,
  PRIMARY KEY (article, comment_id, id),
  FOREIGN KEY (article, comment_id) REFERENCES comments,
  FOREIGN KEY (author)              REFERENCES users,
  CHECK (status IN ('pending', 'approved', 'trusted', 'deferred', 'spam',
                    'rejected')),
  CHECK (format IN ('text'))
);

CREATE TABLE user_permissions(
  "user"     INTEGER NOT NULL,
  permission VARCHAR NOT NULL,
  status     BOOLEAN,
  PRIMARY KEY ("user", permission),
  FOREIGN KEY ("user") REFERENCES users
);

CREATE TABLE user_settings(
  "user"  INTEGER NOT NULL,
  setting VARCHAR NOT NULL,
  value   VARCHAR,
  PRIMARY KEY ("user", setting),
  FOREIGN KEY ("user") REFERENCES users
);

COMMIT;