Whitespace consistency.
[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 -- TODO: Change CHAR/SMALLINT to BOOL (still used in a non-bool fashion in PHP code)
8
9 BEGIN;
10 SET client_min_messages = 'ERROR';
11
12 CREATE SEQUENCE user_user_id_seq MINVALUE 0 START WITH 0;
13 CREATE TABLE mwuser ( -- replace reserved word 'user'
14 user_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('user_user_id_seq'),
15 user_name TEXT NOT NULL UNIQUE,
16 user_real_name TEXT,
17 user_password TEXT,
18 user_newpassword TEXT,
19 user_newpass_time TIMESTAMPTZ,
20 user_token TEXT,
21 user_email TEXT,
22 user_email_token TEXT,
23 user_email_token_expires TIMESTAMPTZ,
24 user_email_authenticated TIMESTAMPTZ,
25 user_options TEXT,
26 user_touched TIMESTAMPTZ,
27 user_registration TIMESTAMPTZ,
28 user_editcount INTEGER
29 );
30 CREATE INDEX user_email_token_idx ON mwuser (user_email_token);
31
32 -- Create a dummy user to satisfy fk contraints especially with revisions
33 INSERT INTO mwuser
34 VALUES (DEFAULT,'Anonymous','',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,now(),now());
35
36 CREATE TABLE user_groups (
37 ug_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
38 ug_group TEXT NOT NULL
39 );
40 CREATE UNIQUE INDEX user_groups_unique ON user_groups (ug_user, ug_group);
41
42 CREATE TABLE user_newtalk (
43 user_id INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
44 user_ip TEXT NULL,
45 user_last_timestamp TIMESTAMPTZ
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 CREATE TABLE page_props (
127 pp_page INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE,
128 pp_propname TEXT NOT NULL,
129 pp_value TEXT NOT NULL
130 );
131 ALTER TABLE page_props ADD CONSTRAINT page_props_pk PRIMARY KEY (pp_page,pp_propname);
132 CREATE INDEX page_props_propname ON page_props (pp_propname);
133
134 CREATE TABLE archive (
135 ar_namespace SMALLINT NOT NULL,
136 ar_title TEXT NOT NULL,
137 ar_text TEXT, -- technically should be bytea, but not used anymore
138 ar_page_id INTEGER NULL,
139 ar_parent_id INTEGER NULL,
140 ar_comment TEXT,
141 ar_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
142 ar_user_text TEXT NOT NULL,
143 ar_timestamp TIMESTAMPTZ NOT NULL,
144 ar_minor_edit SMALLINT NOT NULL DEFAULT 0,
145 ar_flags TEXT,
146 ar_rev_id INTEGER,
147 ar_text_id INTEGER,
148 ar_deleted SMALLINT NOT NULL DEFAULT 0,
149 ar_len INTEGER NULL
150 );
151 CREATE INDEX archive_name_title_timestamp ON archive (ar_namespace,ar_title,ar_timestamp);
152 CREATE INDEX archive_user_text ON archive (ar_user_text);
153
154
155 CREATE TABLE redirect (
156 rd_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
157 rd_namespace SMALLINT NOT NULL,
158 rd_title TEXT NOT NULL
159 );
160 CREATE INDEX redirect_ns_title ON redirect (rd_namespace,rd_title,rd_from);
161
162
163 CREATE TABLE pagelinks (
164 pl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
165 pl_namespace SMALLINT NOT NULL,
166 pl_title TEXT NOT NULL
167 );
168 CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_from,pl_namespace,pl_title);
169
170 CREATE TABLE templatelinks (
171 tl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
172 tl_namespace SMALLINT NOT NULL,
173 tl_title TEXT NOT NULL
174 );
175 CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from);
176 CREATE INDEX templatelinks_from ON templatelinks (tl_from);
177
178 CREATE TABLE imagelinks (
179 il_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
180 il_to TEXT NOT NULL
181 );
182 CREATE UNIQUE INDEX il_from ON imagelinks (il_to,il_from);
183
184 CREATE TABLE categorylinks (
185 cl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
186 cl_to TEXT NOT NULL,
187 cl_sortkey TEXT,
188 cl_timestamp TIMESTAMPTZ NOT NULL
189 );
190 CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to);
191 CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey, cl_from);
192
193 CREATE TABLE externallinks (
194 el_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE,
195 el_to TEXT NOT NULL,
196 el_index TEXT NOT NULL
197 );
198 CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to);
199 CREATE INDEX externallinks_index ON externallinks (el_index);
200
201 CREATE TABLE langlinks (
202 ll_from INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE,
203 ll_lang TEXT,
204 ll_title TEXT
205 );
206 CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang);
207 CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title);
208
209
210 CREATE TABLE site_stats (
211 ss_row_id INTEGER NOT NULL UNIQUE,
212 ss_total_views INTEGER DEFAULT 0,
213 ss_total_edits INTEGER DEFAULT 0,
214 ss_good_articles INTEGER DEFAULT 0,
215 ss_total_pages INTEGER DEFAULT -1,
216 ss_users INTEGER DEFAULT -1,
217 ss_active_users INTEGER DEFAULT -1,
218 ss_admins INTEGER DEFAULT -1,
219 ss_images INTEGER DEFAULT 0
220 );
221
222 CREATE TABLE hitcounter (
223 hc_id BIGINT NOT NULL
224 );
225
226
227 CREATE SEQUENCE ipblocks_ipb_id_val;
228 CREATE TABLE ipblocks (
229 ipb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('ipblocks_ipb_id_val'),
230 ipb_address TEXT NULL,
231 ipb_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
232 ipb_by INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
233 ipb_by_text TEXT NOT NULL DEFAULT '',
234 ipb_reason TEXT NOT NULL,
235 ipb_timestamp TIMESTAMPTZ NOT NULL,
236 ipb_auto SMALLINT NOT NULL DEFAULT 0,
237 ipb_anon_only SMALLINT NOT NULL DEFAULT 0,
238 ipb_create_account SMALLINT NOT NULL DEFAULT 1,
239 ipb_enable_autoblock SMALLINT NOT NULL DEFAULT 1,
240 ipb_expiry TIMESTAMPTZ NOT NULL,
241 ipb_range_start TEXT,
242 ipb_range_end TEXT,
243 ipb_deleted SMALLINT NOT NULL DEFAULT 0,
244 ipb_block_email SMALLINT NOT NULL DEFAULT 0,
245 ipb_allow_usertalk SMALLINT NOT NULL DEFAULT 0
246
247 );
248 CREATE UNIQUE INDEX ipb_address_unique ON ipblocks (ipb_address,ipb_user,ipb_auto,ipb_anon_only);
249 CREATE INDEX ipb_user ON ipblocks (ipb_user);
250 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
251
252
253 CREATE TABLE image (
254 img_name TEXT NOT NULL PRIMARY KEY,
255 img_size INTEGER NOT NULL,
256 img_width INTEGER NOT NULL,
257 img_height INTEGER NOT NULL,
258 img_metadata BYTEA NOT NULL DEFAULT '',
259 img_bits SMALLINT,
260 img_media_type TEXT,
261 img_major_mime TEXT DEFAULT 'unknown',
262 img_minor_mime TEXT DEFAULT 'unknown',
263 img_description TEXT NOT NULL,
264 img_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
265 img_user_text TEXT NOT NULL,
266 img_timestamp TIMESTAMPTZ,
267 img_sha1 TEXT NOT NULL DEFAULT ''
268 );
269 CREATE INDEX img_size_idx ON image (img_size);
270 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
271 CREATE INDEX img_sha1 ON image (img_sha1);
272
273 CREATE TABLE oldimage (
274 oi_name TEXT NOT NULL,
275 oi_archive_name TEXT NOT NULL,
276 oi_size INTEGER NOT NULL,
277 oi_width INTEGER NOT NULL,
278 oi_height INTEGER NOT NULL,
279 oi_bits SMALLINT NOT NULL,
280 oi_description TEXT,
281 oi_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
282 oi_user_text TEXT NOT NULL,
283 oi_timestamp TIMESTAMPTZ NOT NULL,
284 oi_metadata BYTEA NOT NULL DEFAULT '',
285 oi_media_type TEXT NULL,
286 oi_major_mime TEXT NOT NULL DEFAULT 'unknown',
287 oi_minor_mime TEXT NOT NULL DEFAULT 'unknown',
288 oi_deleted SMALLINT NOT NULL DEFAULT 0,
289 oi_sha1 TEXT NOT NULL DEFAULT ''
290 );
291 ALTER TABLE oldimage ADD CONSTRAINT oldimage_oi_name_fkey_cascade FOREIGN KEY (oi_name) REFERENCES image(img_name) ON DELETE CASCADE;
292 CREATE INDEX oi_name_timestamp ON oldimage (oi_name,oi_timestamp);
293 CREATE INDEX oi_name_archive_name ON oldimage (oi_name,oi_archive_name);
294 CREATE INDEX oi_sha1 ON oldimage (oi_sha1);
295
296
297 CREATE SEQUENCE filearchive_fa_id_seq;
298 CREATE TABLE filearchive (
299 fa_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('filearchive_fa_id_seq'),
300 fa_name TEXT NOT NULL,
301 fa_archive_name TEXT,
302 fa_storage_group TEXT,
303 fa_storage_key TEXT,
304 fa_deleted_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
305 fa_deleted_timestamp TIMESTAMPTZ NOT NULL,
306 fa_deleted_reason TEXT,
307 fa_size INTEGER NOT NULL,
308 fa_width INTEGER NOT NULL,
309 fa_height INTEGER NOT NULL,
310 fa_metadata BYTEA NOT NULL DEFAULT '',
311 fa_bits SMALLINT,
312 fa_media_type TEXT,
313 fa_major_mime TEXT DEFAULT 'unknown',
314 fa_minor_mime TEXT DEFAULT 'unknown',
315 fa_description TEXT NOT NULL,
316 fa_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
317 fa_user_text TEXT NOT NULL,
318 fa_timestamp TIMESTAMPTZ,
319 fa_deleted SMALLINT NOT NULL DEFAULT 0
320 );
321 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
322 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
323 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
324 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
325
326
327 CREATE SEQUENCE rc_rc_id_seq;
328 CREATE TABLE recentchanges (
329 rc_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('rc_rc_id_seq'),
330 rc_timestamp TIMESTAMPTZ NOT NULL,
331 rc_cur_time TIMESTAMPTZ NOT NULL,
332 rc_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
333 rc_user_text TEXT NOT NULL,
334 rc_namespace SMALLINT NOT NULL,
335 rc_title TEXT NOT NULL,
336 rc_comment TEXT,
337 rc_minor SMALLINT NOT NULL DEFAULT 0,
338 rc_bot SMALLINT NOT NULL DEFAULT 0,
339 rc_new SMALLINT NOT NULL DEFAULT 0,
340 rc_cur_id INTEGER NULL REFERENCES page(page_id) ON DELETE SET NULL,
341 rc_this_oldid INTEGER NOT NULL,
342 rc_last_oldid INTEGER NOT NULL,
343 rc_type SMALLINT NOT NULL DEFAULT 0,
344 rc_moved_to_ns SMALLINT,
345 rc_moved_to_title TEXT,
346 rc_patrolled SMALLINT NOT NULL DEFAULT 0,
347 rc_ip CIDR,
348 rc_old_len INTEGER,
349 rc_new_len INTEGER,
350 rc_deleted SMALLINT NOT NULL DEFAULT 0,
351 rc_logid INTEGER NOT NULL DEFAULT 0,
352 rc_log_type TEXT,
353 rc_log_action TEXT,
354 rc_params TEXT
355 );
356 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
357 CREATE INDEX rc_timestamp_bot ON recentchanges (rc_timestamp) WHERE rc_bot = 0;
358 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
359 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
360 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
361 CREATE INDEX rc_ip ON recentchanges (rc_ip);
362
363
364 CREATE TABLE watchlist (
365 wl_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE,
366 wl_namespace SMALLINT NOT NULL DEFAULT 0,
367 wl_title TEXT NOT NULL,
368 wl_notificationtimestamp TIMESTAMPTZ
369 );
370 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
371 CREATE INDEX wl_user ON watchlist (wl_user);
372
373 CREATE TABLE math (
374 math_inputhash BYTEA NOT NULL UNIQUE,
375 math_outputhash BYTEA NOT NULL,
376 math_html_conservativeness SMALLINT NOT NULL,
377 math_html TEXT,
378 math_mathml TEXT
379 );
380
381
382 CREATE TABLE interwiki (
383 iw_prefix TEXT NOT NULL UNIQUE,
384 iw_url TEXT NOT NULL,
385 iw_local SMALLINT NOT NULL,
386 iw_trans SMALLINT NOT NULL DEFAULT 0
387 );
388
389
390 CREATE TABLE querycache (
391 qc_type TEXT NOT NULL,
392 qc_value INTEGER NOT NULL,
393 qc_namespace SMALLINT NOT NULL,
394 qc_title TEXT NOT NULL
395 );
396 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
397
398 CREATE TABLE querycache_info (
399 qci_type TEXT UNIQUE,
400 qci_timestamp TIMESTAMPTZ NULL
401 );
402
403 CREATE TABLE querycachetwo (
404 qcc_type TEXT NOT NULL,
405 qcc_value INTEGER NOT NULL DEFAULT 0,
406 qcc_namespace INTEGER NOT NULL DEFAULT 0,
407 qcc_title TEXT NOT NULL DEFAULT '',
408 qcc_namespacetwo INTEGER NOT NULL DEFAULT 0,
409 qcc_titletwo TEXT NOT NULL DEFAULT ''
410 );
411 CREATE INDEX querycachetwo_type_value ON querycachetwo (qcc_type, qcc_value);
412 CREATE INDEX querycachetwo_title ON querycachetwo (qcc_type,qcc_namespace,qcc_title);
413 CREATE INDEX querycachetwo_titletwo ON querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
414
415 CREATE TABLE objectcache (
416 keyname TEXT UNIQUE,
417 value BYTEA NOT NULL DEFAULT '',
418 exptime TIMESTAMPTZ NOT NULL
419 );
420 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
421
422 CREATE TABLE transcache (
423 tc_url TEXT NOT NULL UNIQUE,
424 tc_contents TEXT NOT NULL,
425 tc_time TIMESTAMPTZ NOT NULL
426 );
427
428
429 CREATE SEQUENCE log_log_id_seq;
430 CREATE TABLE logging (
431 log_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('log_log_id_seq'),
432 log_type TEXT NOT NULL,
433 log_action TEXT NOT NULL,
434 log_timestamp TIMESTAMPTZ NOT NULL,
435 log_user INTEGER REFERENCES mwuser(user_id) ON DELETE SET NULL,
436 log_namespace SMALLINT NOT NULL,
437 log_title TEXT NOT NULL,
438 log_comment TEXT,
439 log_params TEXT,
440 log_deleted SMALLINT NOT NULL DEFAULT 0
441 );
442 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
443 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
444 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
445
446
447 CREATE SEQUENCE trackbacks_tb_id_seq;
448 CREATE TABLE trackbacks (
449 tb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('trackbacks_tb_id_seq'),
450 tb_page INTEGER REFERENCES page(page_id) ON DELETE CASCADE,
451 tb_title TEXT NOT NULL,
452 tb_url TEXT NOT NULL,
453 tb_ex TEXT,
454 tb_name TEXT
455 );
456 CREATE INDEX trackback_page ON trackbacks (tb_page);
457
458
459 CREATE SEQUENCE job_job_id_seq;
460 CREATE TABLE job (
461 job_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
462 job_cmd TEXT NOT NULL,
463 job_namespace SMALLINT NOT NULL,
464 job_title TEXT NOT NULL,
465 job_params TEXT NOT NULL
466 );
467 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
468
469 -- Tsearch2 2 stuff. Will fail if we don't have proper access to the tsearch2 tables
470 -- Note: if version 8.3 or higher, we remove the 'default' arg
471 -- Make sure you also change patch-tsearch2funcs.sql if the funcs below change.
472
473 ALTER TABLE page ADD titlevector tsvector;
474 CREATE FUNCTION ts2_page_title() RETURNS TRIGGER LANGUAGE plpgsql AS
475 $mw$
476 BEGIN
477 IF TG_OP = 'INSERT' THEN
478 NEW.titlevector = to_tsvector('default',REPLACE(NEW.page_title,'/',' '));
479 ELSIF NEW.page_title != OLD.page_title THEN
480 NEW.titlevector := to_tsvector('default',REPLACE(NEW.page_title,'/',' '));
481 END IF;
482 RETURN NEW;
483 END;
484 $mw$;
485
486 CREATE TRIGGER ts2_page_title BEFORE INSERT OR UPDATE ON page
487 FOR EACH ROW EXECUTE PROCEDURE ts2_page_title();
488
489
490 ALTER TABLE pagecontent ADD textvector tsvector;
491 CREATE FUNCTION ts2_page_text() RETURNS TRIGGER LANGUAGE plpgsql AS
492 $mw$
493 BEGIN
494 IF TG_OP = 'INSERT' THEN
495 NEW.textvector = to_tsvector('default',NEW.old_text);
496 ELSIF NEW.old_text != OLD.old_text THEN
497 NEW.textvector := to_tsvector('default',NEW.old_text);
498 END IF;
499 RETURN NEW;
500 END;
501 $mw$;
502
503 CREATE TRIGGER ts2_page_text BEFORE INSERT OR UPDATE ON pagecontent
504 FOR EACH ROW EXECUTE PROCEDURE ts2_page_text();
505
506 -- These are added by the setup script due to version compatibility issues
507 -- If using 8.1, we switch from "gin" to "gist"
508
509 CREATE INDEX ts2_page_title ON page USING gin(titlevector);
510 CREATE INDEX ts2_page_text ON pagecontent USING gin(textvector);
511
512 CREATE FUNCTION add_interwiki (TEXT,INT,SMALLINT) RETURNS INT LANGUAGE SQL AS
513 $mw$
514 INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
515 SELECT 1;
516 $mw$;
517
518 -- This table is not used unless profiling is turned on
519 CREATE TABLE profiling (
520 pf_count INTEGER NOT NULL DEFAULT 0,
521 pf_time NUMERIC(18,10) NOT NULL DEFAULT 0,
522 pf_memory NUMERIC(18,10) NOT NULL DEFAULT 0,
523 pf_name TEXT NOT NULL,
524 pf_server TEXT NULL
525 );
526 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
527
528 CREATE TABLE protected_titles (
529 pt_namespace SMALLINT NOT NULL,
530 pt_title TEXT NOT NULL,
531 pt_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL,
532 pt_reason TEXT NULL,
533 pt_timestamp TIMESTAMPTZ NOT NULL,
534 pt_expiry TIMESTAMPTZ NULL,
535 pt_create_perm TEXT NOT NULL DEFAULT ''
536 );
537 CREATE UNIQUE INDEX protected_titles_unique ON protected_titles(pt_namespace, pt_title);
538
539
540 CREATE TABLE updatelog (
541 ul_key TEXT NOT NULL PRIMARY KEY
542 );
543
544
545 CREATE SEQUENCE category_id_seq;
546 CREATE TABLE category (
547 cat_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('category_id_seq'),
548 cat_title TEXT NOT NULL,
549 cat_pages INTEGER NOT NULL DEFAULT 0,
550 cat_subcats INTEGER NOT NULL DEFAULT 0,
551 cat_files INTEGER NOT NULL DEFAULT 0,
552 cat_hidden SMALLINT NOT NULL DEFAULT 0
553 );
554 CREATE UNIQUE INDEX category_title ON category(cat_title);
555 CREATE INDEX category_pages ON category(cat_pages);
556
557 CREATE TABLE change_tag (
558 ct_rc_id INTEGER NULL,
559 ct_log_id INTEGER NULL,
560 ct_rev_id INTEGER NULL,
561 ct_tag TEXT NOT NULL,
562 ct_params TEXT NULL
563 );
564 CREATE UNIQUE INDEX change_tag_rc_tag ON change_tag(ct_rc_id,ct_tag);
565 CREATE UNIQUE INDEX change_tag_log_tag ON change_tag(ct_log_id,ct_tag);
566 CREATE UNIQUE INDEX change_tag_rev_tag ON change_tag(ct_rev_id,ct_tag);
567 CREATE INDEX change_tag_tag_id ON change_tag(ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
568
569 CREATE TABLE tag_summary (
570 ts_rc_id INTEGER NULL,
571 ts_log_id INTEGER NULL,
572 ts_rev_id INTEGER NULL,
573 ts_tags TEXT NOT NULL
574 );
575 CREATE UNIQUE INDEX tag_summary_rc_id ON tag_summary(ts_rc_id);
576 CREATE UNIQUE INDEX tag_summary_log_id ON tag_summary(ts_log_id);
577 CREATE UNIQUE INDEX tag_summary_rev_id ON tag_summary(ts_rev_id);
578
579 CREATE TABLE valid_tag (
580 vt_tag TEXT NOT NULL PRIMARY KEY
581 );
582
583 CREATE TABLE mediawiki_version (
584 type TEXT NOT NULL,
585 mw_version TEXT NOT NULL,
586 notes TEXT NULL,
587
588 pg_version TEXT NULL,
589 pg_dbname TEXT NULL,
590 pg_user TEXT NULL,
591 pg_port TEXT NULL,
592 mw_schema TEXT NULL,
593 ts2_schema TEXT NULL,
594 ctype TEXT NULL,
595
596 sql_version TEXT NULL,
597 sql_date TEXT NULL,
598 cdate TIMESTAMPTZ NOT NULL DEFAULT now()
599 );
600
601 INSERT INTO mediawiki_version (type,mw_version,sql_version,sql_date)
602 VALUES ('Creation','??','$LastChangedRevision$','$LastChangedDate$');
603