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