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