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
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
|
--*- mode: sql; product: postgres -*--
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,
email VARCHAR,
website VARCHAR,
PRIMARY KEY (id),
CHECK (status IN ('pending', 'approved', 'trusted', 'deferred', 'disabled',
'admin', 'visitor'))
);
CREATE TABLE passwords(
"user" INTEGER NOT NULL,
password VARCHAR NOT NULL,
PRIMARY KEY ("user", password),
FOREIGN KEY ("user") REFERENCES users
);
CREATE TABLE openids(
"user" INTEGER NOT NULL,
openid VARCHAR NOT NULL,
PRIMARY KEY ("user", openid),
FOREIGN KEY ("user") REFERENCES users
);
CREATE TABLE login_certificates(
"user" INTEGER NOT NULL,
certificate BYTEA NOT NULL,
PRIMARY KEY ("user", certificate),
FOREIGN KEY ("user") REFERENCES users
);
CREATE TABLE article_types(
id SERIAL NOT NULL,
name VARCHAR,
page_template VARCHAR,
PRIMARY KEY (id)
);
CREATE TABLE articles(
id SERIAL NOT NULL,
type INTEGER NOT NULL,
PRIMARY KEY (id),
FOREIGN KEY (type) REFERENCES article_types
);
CREATE TABLE article_aliases(
alias VARCHAR NOT NULL,
article INTEGER NOT NULL,
PRIMARY KEY (alias),
FOREIGN KEY (article) REFERENCES articles
);
CREATE TABLE journals(
id INTEGER NOT NULL,
path_prefix VARCHAR, --can be null to make the journal unreachable
PRIMARY KEY (id)
);
CREATE TABLE journal_entries(
journal INTEGER NOT NULL,
index INTEGER NOT NULL,
article INTEGER NOT NULL,
PRIMARY KEY (journal, index),
FOREIGN KEY (article) REFERENCES articles,
FOREIGN KEY (journal) REFERENCES journals,
CHECK (index >= 0)
);
CREATE TABLE comments(
id SERIAL NOT NULL,
article INTEGER NOT NULL,
global_id VARCHAR,
PRIMARY KEY (id),
FOREIGN KEY (article) REFERENCES articles
);
CREATE TABLE article_revisions(
id SERIAL NOT NULL,
article INTEGER NOT NULL,
date TIMESTAMP DEFAULT now(),
title VARCHAR NOT NULL,
content VARCHAR NOT NULL,
author INTEGER,
format VARCHAR NOT NULL,
status VARCHAR NOT NULL,
global_id VARCHAR,
PRIMARY KEY (id),
FOREIGN KEY (article) REFERENCES articles,
FOREIGN KEY (author) REFERENCES users,
CHECK (format IN ('html')),
CHECK (status IN ('draft', 'published', 'syndicated')),
UNIQUE (global_id)
);
CREATE TABLE article_revision_characteristics(
revision INTEGER NOT NULL,
characteristic VARCHAR NOT NULL,
value VARCHAR,
FOREIGN KEY (revision) REFERENCES article_revisions,
UNIQUE (revision, characteristic, value)
);
CREATE TABLE article_revision_parenthood(
parent INTEGER NOT NULL,
child INTEGER NOT NULL,
PRIMARY KEY (parent, child),
FOREIGN KEY (parent) REFERENCES article_revisions,
FOREIGN KEY (child) REFERENCES article_revisions
);
CREATE TABLE comment_revisions(
id SERIAL NOT NULL,
comment INTEGER NOT NULL,
date TIMESTAMP DEFAULT now(),
content VARCHAR NOT NULL,
author INTEGER,
format VARCHAR NOT NULL,
status VARCHAR NOT NULL,
article_revision INTEGER,
submitter_ip INET,
submitter_user_agent VARCHAR,
PRIMARY KEY (id),
FOREIGN KEY (comment) REFERENCES comments,
FOREIGN KEY (author) REFERENCES users,
CHECK (status IN ('pending', 'approved', 'trusted', 'deferred', 'spam',
'rejected')),
CHECK (format IN ('text'))
);
CREATE TABLE categories(
id SERIAL NOT NULL,
name VARCHAR NOT NULL,
PRIMARY KEY (id)
);
CREATE TABLE category_inclusions(
category INTEGER NOT NULL,
supercategory INTEGER NOT NULL,
PRIMARY KEY (category, supercategory),
FOREIGN KEY (category) REFERENCES categories,
FOREIGN KEY (supercategory) REFERENCES categories
);
CREATE TABLE article_category_memberships(
article INTEGER NOT NULL,
category VARCHAR NOT NULL,
PRIMARY KEY (article, category),
FOREIGN KEY (article) REFERENCES articles
);
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
);
CREATE TABLE used_transaction_keys(
key BIGINT,
PRIMARY KEY (key)
);
CREATE SEQUENCE transaction_key_seq;
CREATE TABLE cached_pages(
alias VARCHAR NOT NULL,
characteristic_hash INTEGER NOT NULL,
date TIMESTAMP NOT NULL DEFAULT now(),
content VARCHAR NOT NULL,
PRIMARY KEY(alias, characteristic_hash)
);
----
CREATE TYPE characteristic AS (
characteristic VARCHAR,
value VARCHAR
);
CREATE TYPE characteristic_list AS (
characteristics characteristic[]
);
CREATE OR REPLACE FUNCTION article_revisions_for_characteristics(
article INTEGER,
characteristic_lists characteristic_list[]
) RETURNS SETOF INTEGER AS $BODY$
DECLARE
query VARCHAR;
required_chars RECORD;
charac RECORD;
BEGIN
FOR required_chars IN SELECT unnest(characteristic_lists) AS val LOOP
query := $$SELECT id FROM article_revisions
WHERE article = $$
|| quote_literal(article) ||
$$ AND status IN ('published', 'syndicated')$$;
FOR charac IN SELECT unnest((required_chars.val::characteristic_list).characteristics) AS val LOOP
query := query || $$ AND EXISTS
(SELECT 1
FROM article_revision_characteristics
WHERE revision = article_revisions.id
AND characteristic = $$ || quote_literal((charac.val::characteristic).characteristic) || $$
AND value = $$ || quote_literal((charac.val::characteristic).value) || $$)$$;
END LOOP;
query := query || $$ ORDER BY DATE DESC$$;
FOUND := false;
RETURN QUERY EXECUTE query;
IF FOUND THEN
RETURN;
END IF;
END LOOP;
END
$BODY$ LANGUAGE plpgsql STABLE;
-- Usage example:
-- SELECT article_revisions_for_characteristics(70, ARRAY[ROW(ARRAY[ROW('language', 'de')::characteristic])]::characteristic_list[]);
CREATE FUNCTION older_revision(
IN article_revisions,
IN article_revisions,
OUT article_revisions
) AS $$
SELECT $1 WHERE $1.date < $2.date OR $2.date IS NULL
UNION
SELECT $2 WHERE $1.date >= $2.date OR $1.date IS NULL
UNION
SELECT $1 WHERE $1.date IS NULL AND $2.date IS NULL
$$ LANGUAGE SQL IMMUTABLE;
CREATE AGGREGATE oldest_revision (article_revisions) (
SFUNC = older_revision,
STYPE = article_revisions
);
CREATE FUNCTION more_recent_revision(
IN article_revisions,
IN article_revisions,
OUT article_revisions
) AS $$
SELECT $1 WHERE $1.date > $2.date OR $2.date IS NULL
UNION
SELECT $2 WHERE $1.date <= $2.date OR $1.date IS NULL
UNION
SELECT $1 WHERE $1.date IS NULL AND $2.date IS NULL
$$ LANGUAGE SQL IMMUTABLE;
CREATE AGGREGATE most_recent_revision (article_revisions) (
SFUNC = more_recent_revision,
STYPE = article_revisions
);
CREATE VIEW article_comment_counts AS
SELECT a.id AS article,
count(c.*) AS comment_count
FROM articles a
LEFT OUTER JOIN comments c
ON c.article = a.id
AND EXISTS (SELECT *
FROM comment_revisions
WHERE comment = c.id
AND status IN ('approved', 'trusted'))
GROUP BY a.id;
CREATE VIEW article_publishing_dates AS
SELECT article AS article,
min(date) AS publishing_date
FROM article_revisions
WHERE status IN ('published', 'syndicated')
GROUP BY article;
CREATE VIEW article_branch_tips AS
SELECT article AS article,
article_revisions.id AS revision
FROM (SELECT id FROM article_revisions
EXCEPT
SELECT parent FROM article_revision_parenthood)
AS branch_tips
JOIN article_revisions USING (id);
-- You can customize the following depending on which languages you
-- support on your web site.
CREATE INDEX article_revisions_german_ts_idx
ON article_revisions
USING gin((setweight(to_tsvector('german', title), 'A')
|| setweight(to_tsvector('german', content), 'D')));
CREATE INDEX article_revisions_english_ts_idx
ON article_revisions
USING gin((setweight(to_tsvector('english', title), 'A')
|| setweight(to_tsvector('english', content), 'D')));
CREATE INDEX article_revisions_french_ts_idx
ON article_revisions
USING gin((setweight(to_tsvector('french', title), 'A')
|| setweight(to_tsvector('french', content), 'D')));
CREATE FUNCTION do_full_text_search(query tsquery,
language regconfig,
max_results INTEGER)
RETURNS SETOF record
AS $$
WITH headline_options AS (
SELECT 'StartSel=<strong>,StopSel=</strong>,FragmentDelimiter=" ... "'::varchar
AS headline_options
), search AS (
SELECT revision,
ts_rank(( setweight(to_tsvector($2, title), 'A')
|| setweight(to_tsvector($2, content), 'D')),
$1,
1)
AS rank,
title,
content
FROM article_branch_tips
JOIN article_revisions ON revision = id
ORDER BY rank DESC
LIMIT $3
)
SELECT rank,
revision,
ts_headline(content, $1, headline_options),
ts_headline(title, $1, headline_options)
FROM search
CROSS JOIN headline_options
$$ LANGUAGE SQL STABLE;
COMMIT;
|