Have update.php change the functions to their new builtin tsearch2 versions if Postgr...
[lhc/web/wiklou.git] / maintenance / postgres / tables.sql
1 -- SQL to create the initial tables for the MediaWiki database.
2 -- This is read and executed by the install script; you should
3 -- not have to run it by itself unless doing a manual install.
4 -- This is the PostgreSQL version.
5 -- For information about each table, please see the notes in maintenance/tables.sql
6 -- Please make sure all dollar-quoting uses $mw$ at the start of the line
7 -- We can't use SERIAL everywhere: the sequence names are hard-coded into the PHP
8 -- TODO: Change CHAR/SMALLINT to BOOL (still needed as CHAR due to some PHP code)
9
10 BEGIN;
11 SET client_min_messages = 'ERROR';
12
13 CREATE SEQUENCE user_user_id_seq MINVALUE 0 START WITH 0;
14 CREATE TABLE mwuser ( -- replace reserved word 'user'
15 user_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('user_user_id_seq'),
16 user_name TEXT NOT NULL UNIQUE,
17 user_real_name TEXT,
18 user_password TEXT,
19 user_newpassword TEXT,
20 user_newpass_time TIMESTAMPTZ,
21 user_token TEXT,
22 user_email TEXT,
23 user_email_token TEXT,
24 user_email_token_expires TIMESTAMPTZ,
25 user_email_authenticated TIMESTAMPTZ,
26 user_options TEXT,
27 user_touched TIMESTAMPTZ,
28 user_registration TIMESTAMPTZ,
29 user_editcount INTEGER
30 );
31 CREATE INDEX user_email_token_idx ON mwuser (user_email_token);
32
33 -- Create a dummy user to satisfy fk contraints especially with revisions
34 INSERT INTO mwuser
35 VALUES (DEFAULT,'Anonymous','',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,now(),now());
36
37 CREATE TABLE user_groups (
38 ug_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
39 ug_group TEXT NOT NULL
40 );
41 CREATE UNIQUE INDEX user_groups_unique ON user_groups (ug_user, ug_group);
42
43 CREATE TABLE user_newtalk (
44 user_id INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
45 user_ip TEXT NULL
46 );
47 CREATE INDEX user_newtalk_id_idx ON user_newtalk (user_id);
48 CREATE INDEX user_newtalk_ip_idx ON user_newtalk (user_ip);
49
50
51 CREATE SEQUENCE page_page_id_seq;
52 CREATE TABLE page (
53 page_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('page_page_id_seq'),
54 page_namespace SMALLINT NOT NULL,
55 page_title TEXT NOT NULL,
56 page_restrictions TEXT,
57 page_counter BIGINT NOT NULL DEFAULT 0,
58 page_is_redirect SMALLINT NOT NULL DEFAULT 0,
59 page_is_new SMALLINT NOT NULL DEFAULT 0,
60 page_random NUMERIC(15,14) NOT NULL DEFAULT RANDOM(),
61 page_touched TIMESTAMPTZ,
62 page_latest INTEGER NOT NULL, -- FK?
63 page_len INTEGER NOT NULL
64 );
65 CREATE UNIQUE INDEX page_unique_name ON page (page_namespace, page_title);
66 CREATE INDEX page_main_title ON page (page_title) WHERE page_namespace = 0;
67 CREATE INDEX page_talk_title ON page (page_title) WHERE page_namespace = 1;
68 CREATE INDEX page_user_title ON page (page_title) WHERE page_namespace = 2;
69 CREATE INDEX page_utalk_title ON page (page_title) WHERE page_namespace = 3;
70 CREATE INDEX page_project_title ON page (page_title) WHERE page_namespace = 4;
71 CREATE INDEX page_random_idx ON page (page_random);
72 CREATE INDEX page_len_idx ON page (page_len);
73
74 CREATE FUNCTION page_deleted() RETURNS TRIGGER LANGUAGE plpgsql AS
75 $mw$
76 BEGIN
77 DELETE FROM recentchanges WHERE rc_namespace = OLD.page_namespace AND rc_title = OLD.page_title;
78 RETURN NULL;
79 END;
80 $mw$;
81
82 CREATE TRIGGER page_deleted AFTER DELETE ON page
83 FOR EACH ROW EXECUTE PROCEDURE page_deleted();
84
85 CREATE SEQUENCE rev_rev_id_val;
86 CREATE TABLE revision (
87 rev_id INTEGER NOT NULL UNIQUE DEFAULT nextval('rev_rev_id_val'),
88 rev_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE,
89 rev_text_id INTEGER NULL, -- FK
90 rev_comment TEXT,
91 rev_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE RESTRICT,
92 rev_user_text TEXT NOT NULL,
93 rev_timestamp TIMESTAMPTZ NOT NULL,
94 rev_minor_edit SMALLINT NOT NULL DEFAULT 0,
95 rev_deleted SMALLINT NOT NULL DEFAULT 0,
96 rev_len INTEGER NULL,
97 rev_parent_id INTEGER NULL
98 );
99 CREATE UNIQUE INDEX revision_unique ON revision (rev_page, rev_id);
100 CREATE INDEX rev_text_id_idx ON revision (rev_text_id);
101 CREATE INDEX rev_timestamp_idx ON revision (rev_timestamp);
102 CREATE INDEX rev_user_idx ON revision (rev_user);
103 CREATE INDEX rev_user_text_idx ON revision (rev_user_text);
104
105
106 CREATE SEQUENCE text_old_id_val;
107 CREATE TABLE pagecontent ( -- replaces reserved word 'text'
108 old_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('text_old_id_val'),
109 old_text TEXT,
110 old_flags TEXT
111 );
112
113
114 CREATE SEQUENCE pr_id_val;
115 CREATE TABLE page_restrictions (
116 pr_id INTEGER NOT NULL UNIQUE DEFAULT nextval('pr_id_val'),
117 pr_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE,
118 pr_type TEXT NOT NULL,
119 pr_level TEXT NOT NULL,
120 pr_cascade SMALLINT NOT NULL,
121 pr_user INTEGER NULL,
122 pr_expiry TIMESTAMPTZ NULL
123 );
124 ALTER TABLE page_restrictions ADD CONSTRAINT page_restrictions_pk PRIMARY KEY (pr_page,pr_type);
125
126
127 CREATE TABLE archive (
128 ar_namespace SMALLINT NOT NULL,
129 ar_title TEXT NOT NULL,
130 ar_text TEXT, -- technically should be bytea, but not used anymore
131 ar_page_id INTEGER NULL,
132 ar_comment TEXT,
133 ar_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
134 ar_user_text TEXT NOT NULL,
135 ar_timestamp TIMESTAMPTZ NOT NULL,
136 ar_minor_edit SMALLINT NOT NULL DEFAULT 0,
137 ar_flags TEXT,
138 ar_rev_id INTEGER,
139 ar_text_id INTEGER,
140 ar_deleted SMALLINT NOT NULL DEFAULT 0,
141 ar_len INTEGER NULL
142 );
143 CREATE INDEX archive_name_title_timestamp ON archive (ar_namespace,ar_title,ar_timestamp);
144 CREATE INDEX archive_user_text ON archive (ar_user_text);
145
146
147 CREATE TABLE redirect (
148 rd_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
149 rd_namespace SMALLINT NOT NULL,
150 rd_title TEXT NOT NULL
151 );
152 CREATE INDEX redirect_ns_title ON redirect (rd_namespace,rd_title,rd_from);
153
154
155 CREATE TABLE pagelinks (
156 pl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
157 pl_namespace SMALLINT NOT NULL,
158 pl_title TEXT NOT NULL
159 );
160 CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_from,pl_namespace,pl_title);
161
162 CREATE TABLE templatelinks (
163 tl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
164 tl_namespace SMALLINT NOT NULL,
165 tl_title TEXT NOT NULL
166 );
167 CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from);
168
169 CREATE TABLE imagelinks (
170 il_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
171 il_to TEXT NOT NULL
172 );
173 CREATE UNIQUE INDEX il_from ON imagelinks (il_to,il_from);
174
175 CREATE TABLE categorylinks (
176 cl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
177 cl_to TEXT NOT NULL,
178 cl_sortkey TEXT,
179 cl_timestamp TIMESTAMPTZ NOT NULL
180 );
181 CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to);
182 CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey, cl_from);
183
184 CREATE TABLE externallinks (
185 el_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
186 el_to TEXT NOT NULL,
187 el_index TEXT NOT NULL
188 );
189 CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to);
190 CREATE INDEX externallinks_index ON externallinks (el_index);
191
192 CREATE TABLE langlinks (
193 ll_from INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE,
194 ll_lang TEXT,
195 ll_title TEXT
196 );
197 CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang);
198 CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title);
199
200
201 CREATE TABLE site_stats (
202 ss_row_id INTEGER NOT NULL UNIQUE,
203 ss_total_views INTEGER DEFAULT 0,
204 ss_total_edits INTEGER DEFAULT 0,
205 ss_good_articles INTEGER DEFAULT 0,
206 ss_total_pages INTEGER DEFAULT -1,
207 ss_users INTEGER DEFAULT -1,
208 ss_admins INTEGER DEFAULT -1,
209 ss_images INTEGER DEFAULT 0
210 );
211
212 CREATE TABLE hitcounter (
213 hc_id BIGINT NOT NULL
214 );
215
216
217 CREATE SEQUENCE ipblocks_ipb_id_val;
218 CREATE TABLE ipblocks (
219 ipb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('ipblocks_ipb_id_val'),
220 ipb_address TEXT NULL,
221 ipb_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
222 ipb_by INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
223 ipb_by_text TEXT NOT NULL DEFAULT '',
224 ipb_reason TEXT NOT NULL,
225 ipb_timestamp TIMESTAMPTZ NOT NULL,
226 ipb_auto SMALLINT NOT NULL DEFAULT 0,
227 ipb_anon_only SMALLINT NOT NULL DEFAULT 0,
228 ipb_create_account SMALLINT NOT NULL DEFAULT 1,
229 ipb_enable_autoblock SMALLINT NOT NULL DEFAULT 1,
230 ipb_expiry TIMESTAMPTZ NOT NULL,
231 ipb_range_start TEXT,
232 ipb_range_end TEXT,
233 ipb_deleted SMALLINT NOT NULL DEFAULT 0,
234 ipb_block_email SMALLINT NOT NULL DEFAULT 0
235
236 );
237 CREATE INDEX ipb_address ON ipblocks (ipb_address);
238 CREATE INDEX ipb_user ON ipblocks (ipb_user);
239 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
240
241
242 CREATE TABLE image (
243 img_name TEXT NOT NULL PRIMARY KEY,
244 img_size INTEGER NOT NULL,
245 img_width INTEGER NOT NULL,
246 img_height INTEGER NOT NULL,
247 img_metadata BYTEA NOT NULL DEFAULT '',
248 img_bits SMALLINT,
249 img_media_type TEXT,
250 img_major_mime TEXT DEFAULT 'unknown',
251 img_minor_mime TEXT DEFAULT 'unknown',
252 img_description TEXT NOT NULL,
253 img_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
254 img_user_text TEXT NOT NULL,
255 img_timestamp TIMESTAMPTZ,
256 img_sha1 TEXT NOT NULL DEFAULT ''
257 );
258 CREATE INDEX img_size_idx ON image (img_size);
259 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
260 CREATE INDEX img_sha1 ON image (img_sha1);
261
262 CREATE TABLE oldimage (
263 oi_name TEXT NOT NULL,
264 oi_archive_name TEXT NOT NULL,
265 oi_size INTEGER NOT NULL,
266 oi_width INTEGER NOT NULL,
267 oi_height INTEGER NOT NULL,
268 oi_bits SMALLINT NOT NULL,
269 oi_description TEXT,
270 oi_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
271 oi_user_text TEXT NOT NULL,
272 oi_timestamp TIMESTAMPTZ NOT NULL,
273 oi_metadata BYTEA NOT NULL DEFAULT '',
274 oi_media_type TEXT NULL,
275 oi_major_mime TEXT NOT NULL DEFAULT 'unknown',
276 oi_minor_mime TEXT NOT NULL DEFAULT 'unknown',
277 oi_deleted SMALLINT NOT NULL DEFAULT 0,
278 oi_sha1 TEXT NOT NULL DEFAULT ''
279 );
280 ALTER TABLE oldimage ADD CONSTRAINT oldimage_oi_name_fkey_cascade FOREIGN KEY (oi_name) REFERENCES image(img_name) ON DELETE CASCADE;
281 CREATE INDEX oi_name_timestamp ON oldimage (oi_name,oi_timestamp);
282 CREATE INDEX oi_name_archive_name ON oldimage (oi_name,oi_archive_name);
283 CREATE INDEX oi_sha1 ON oldimage (oi_sha1);
284
285
286 CREATE TABLE filearchive (
287 fa_id SERIAL NOT NULL PRIMARY KEY,
288 fa_name TEXT NOT NULL,
289 fa_archive_name TEXT,
290 fa_storage_group TEXT,
291 fa_storage_key TEXT,
292 fa_deleted_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
293 fa_deleted_timestamp TIMESTAMPTZ NOT NULL,
294 fa_deleted_reason TEXT,
295 fa_size INTEGER NOT NULL,
296 fa_width INTEGER NOT NULL,
297 fa_height INTEGER NOT NULL,
298 fa_metadata BYTEA NOT NULL DEFAULT '',
299 fa_bits SMALLINT,
300 fa_media_type TEXT,
301 fa_major_mime TEXT DEFAULT 'unknown',
302 fa_minor_mime TEXT DEFAULT 'unknown',
303 fa_description TEXT NOT NULL,
304 fa_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
305 fa_user_text TEXT NOT NULL,
306 fa_timestamp TIMESTAMPTZ,
307 fa_deleted SMALLINT NOT NULL DEFAULT 0
308 );
309 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
310 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
311 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
312 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
313
314
315 CREATE SEQUENCE rc_rc_id_seq;
316 CREATE TABLE recentchanges (
317 rc_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('rc_rc_id_seq'),
318 rc_timestamp TIMESTAMPTZ NOT NULL,
319 rc_cur_time TIMESTAMPTZ NOT NULL,
320 rc_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
321 rc_user_text TEXT NOT NULL,
322 rc_namespace SMALLINT NOT NULL,
323 rc_title TEXT NOT NULL,
324 rc_comment TEXT,
325 rc_minor SMALLINT NOT NULL DEFAULT 0,
326 rc_bot SMALLINT NOT NULL DEFAULT 0,
327 rc_new SMALLINT NOT NULL DEFAULT 0,
328 rc_cur_id INTEGER NULL REFERENCES page(page_id) ON DELETE SET NULL,
329 rc_this_oldid INTEGER NOT NULL,
330 rc_last_oldid INTEGER NOT NULL,
331 rc_type SMALLINT NOT NULL DEFAULT 0,
332 rc_moved_to_ns SMALLINT,
333 rc_moved_to_title TEXT,
334 rc_patrolled SMALLINT NOT NULL DEFAULT 0,
335 rc_ip CIDR,
336 rc_old_len INTEGER,
337 rc_new_len INTEGER,
338 rc_deleted SMALLINT NOT NULL DEFAULT 0,
339 rc_logid INTEGER NOT NULL DEFAULT 0,
340 rc_log_type TEXT,
341 rc_log_action TEXT,
342 rc_params TEXT
343 );
344 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
345 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
346 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
347 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
348 CREATE INDEX rc_ip ON recentchanges (rc_ip);
349
350
351 CREATE TABLE watchlist (
352 wl_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
353 wl_namespace SMALLINT NOT NULL DEFAULT 0,
354 wl_title TEXT NOT NULL,
355 wl_notificationtimestamp TIMESTAMPTZ
356 );
357 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
358
359
360 CREATE TABLE math (
361 math_inputhash BYTEA NOT NULL UNIQUE,
362 math_outputhash BYTEA NOT NULL,
363 math_html_conservativeness SMALLINT NOT NULL,
364 math_html TEXT,
365 math_mathml TEXT
366 );
367
368
369 CREATE TABLE interwiki (
370 iw_prefix TEXT NOT NULL UNIQUE,
371 iw_url TEXT NOT NULL,
372 iw_local SMALLINT NOT NULL,
373 iw_trans SMALLINT NOT NULL DEFAULT 0
374 );
375
376
377 CREATE TABLE querycache (
378 qc_type TEXT NOT NULL,
379 qc_value INTEGER NOT NULL,
380 qc_namespace SMALLINT NOT NULL,
381 qc_title TEXT NOT NULL
382 );
383 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
384
385 CREATE TABLE querycache_info (
386 qci_type TEXT UNIQUE,
387 qci_timestamp TIMESTAMPTZ NULL
388 );
389
390 CREATE TABLE querycachetwo (
391 qcc_type TEXT NOT NULL,
392 qcc_value INTEGER NOT NULL DEFAULT 0,
393 qcc_namespace INTEGER NOT NULL DEFAULT 0,
394 qcc_title TEXT NOT NULL DEFAULT '',
395 qcc_namespacetwo INTEGER NOT NULL DEFAULT 0,
396 qcc_titletwo TEXT NOT NULL DEFAULT ''
397 );
398 CREATE INDEX querycachetwo_type_value ON querycachetwo (qcc_type, qcc_value);
399 CREATE INDEX querycachetwo_title ON querycachetwo (qcc_type,qcc_namespace,qcc_title);
400 CREATE INDEX querycachetwo_titletwo ON querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
401
402 CREATE TABLE objectcache (
403 keyname TEXT UNIQUE,
404 value BYTEA NOT NULL DEFAULT '',
405 exptime TIMESTAMPTZ NOT NULL
406 );
407 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
408
409 CREATE TABLE transcache (
410 tc_url TEXT NOT NULL UNIQUE,
411 tc_contents TEXT NOT NULL,
412 tc_time TIMESTAMPTZ NOT NULL
413 );
414
415
416 CREATE SEQUENCE log_log_id_seq;
417 CREATE TABLE logging (
418 log_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('log_log_id_seq'),
419 log_type TEXT NOT NULL,
420 log_action TEXT NOT NULL,
421 log_timestamp TIMESTAMPTZ NOT NULL,
422 log_user INTEGER REFERENCES mwuser(user_id) ON DELETE SET NULL,
423 log_namespace SMALLINT NOT NULL,
424 log_title TEXT NOT NULL,
425 log_comment TEXT,
426 log_params TEXT,
427 log_deleted SMALLINT NOT NULL DEFAULT 0
428 );
429 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
430 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
431 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
432
433
434 CREATE TABLE trackbacks (
435 tb_id SERIAL NOT NULL PRIMARY KEY,
436 tb_page INTEGER REFERENCES page(page_id) ON DELETE CASCADE,
437 tb_title TEXT NOT NULL,
438 tb_url TEXT NOT NULL,
439 tb_ex TEXT,
440 tb_name TEXT
441 );
442 CREATE INDEX trackback_page ON trackbacks (tb_page);
443
444
445 CREATE SEQUENCE job_job_id_seq;
446 CREATE TABLE job (
447 job_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
448 job_cmd TEXT NOT NULL,
449 job_namespace SMALLINT NOT NULL,
450 job_title TEXT NOT NULL,
451 job_params TEXT NOT NULL
452 );
453 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
454
455 -- Tsearch2 2 stuff. Will fail if we don't have proper access to the tsearch2 tables
456 -- Note: if version 8.3 or higher, we remove the 'default' arg
457 -- Make sure you also change patch-tsearch2funcs.sql if the funcs below change.
458
459 ALTER TABLE page ADD titlevector tsvector;
460 CREATE FUNCTION ts2_page_title() RETURNS TRIGGER LANGUAGE plpgsql AS
461 $mw$
462 BEGIN
463 IF TG_OP = 'INSERT' THEN
464 NEW.titlevector = to_tsvector('default',REPLACE(NEW.page_title,'/',' '));
465 ELSIF NEW.page_title != OLD.page_title THEN
466 NEW.titlevector := to_tsvector('default',REPLACE(NEW.page_title,'/',' '));
467 END IF;
468 RETURN NEW;
469 END;
470 $mw$;
471
472 CREATE TRIGGER ts2_page_title BEFORE INSERT OR UPDATE ON page
473 FOR EACH ROW EXECUTE PROCEDURE ts2_page_title();
474
475
476 ALTER TABLE pagecontent ADD textvector tsvector;
477 CREATE FUNCTION ts2_page_text() RETURNS TRIGGER LANGUAGE plpgsql AS
478 $mw$
479 BEGIN
480 IF TG_OP = 'INSERT' THEN
481 NEW.textvector = to_tsvector('default',NEW.old_text);
482 ELSIF NEW.old_text != OLD.old_text THEN
483 NEW.textvector := to_tsvector('default',NEW.old_text);
484 END IF;
485 RETURN NEW;
486 END;
487 $mw$;
488
489 CREATE TRIGGER ts2_page_text BEFORE INSERT OR UPDATE ON pagecontent
490 FOR EACH ROW EXECUTE PROCEDURE ts2_page_text();
491
492 -- These are added by the setup script due to version compatibility issues
493 -- If using 8.1, we switch from "gin" to "gist"
494
495 CREATE INDEX ts2_page_title ON page USING gin(titlevector);
496 CREATE INDEX ts2_page_text ON pagecontent USING gin(textvector);
497
498 CREATE FUNCTION add_interwiki (TEXT,INT,SMALLINT) RETURNS INT LANGUAGE SQL AS
499 $mw$
500 INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
501 SELECT 1;
502 $mw$;
503
504 -- This table is not used unless profiling is turned on
505 CREATE TABLE profiling (
506 pf_count INTEGER NOT NULL DEFAULT 0,
507 pf_time NUMERIC(18,10) NOT NULL DEFAULT 0,
508 pf_name TEXT NOT NULL,
509 pf_server TEXT NULL
510 );
511 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
512
513 CREATE TABLE protected_titles (
514 pt_namespace SMALLINT NOT NULL,
515 pt_title TEXT NOT NULL,
516 pt_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
517 pt_reason TEXT NULL,
518 pt_timestamp TIMESTAMPTZ NOT NULL,
519 pt_expiry TIMESTAMPTZ NULL,
520 pt_create_perm TEXT NOT NULL DEFAULT ''
521 );
522 CREATE UNIQUE INDEX protected_titles_unique ON protected_titles(pt_namespace, pt_title);
523
524 CREATE TABLE mediawiki_version (
525 type TEXT NOT NULL,
526 mw_version TEXT NOT NULL,
527 notes TEXT NULL,
528
529 pg_version TEXT NULL,
530 pg_dbname TEXT NULL,
531 pg_user TEXT NULL,
532 pg_port TEXT NULL,
533 mw_schema TEXT NULL,
534 ts2_schema TEXT NULL,
535 ctype TEXT NULL,
536
537 sql_version TEXT NULL,
538 sql_date TEXT NULL,
539 cdate TIMESTAMPTZ NOT NULL DEFAULT now()
540 );
541
542 INSERT INTO mediawiki_version (type,mw_version,sql_version,sql_date)
543 VALUES ('Creation','??','$LastChangedRevision$','$LastChangedDate$');
544