MediaWiki database schema for IBM DB2
[lhc/web/wiklou.git] / maintenance / ibm_db2 / tables.sql
1 -- DB2
2
3 -- SQL to create the initial tables for the MediaWiki database.
4 -- This is read and executed by the install script; you should
5 -- not have to run it by itself unless doing a manual install.
6 -- This is the IBM DB2 version.
7 -- For information about each table, please see the notes in maintenance/tables.sql
8
9
10 CREATE TABLE user (
11 user_id INTEGER PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 0),
12 user_name VARCHAR(255) NOT NULL UNIQUE,
13 user_real_name VARCHAR(255),
14 user_password VARCHAR(1024),
15 user_newpassword VARCHAR(1024),
16 user_newpass_time TIMESTAMP(3),
17 user_token VARCHAR(255),
18 user_email VARCHAR(255),
19 user_email_token VARCHAR(255),
20 user_email_token_expires TIMESTAMP(3),
21 user_email_authenticated TIMESTAMP(3),
22 -- obsolete, replace by user_properties table
23 user_options CLOB(64K) INLINE LENGTH 4096,
24 user_touched TIMESTAMP(3),
25 user_registration TIMESTAMP(3),
26 user_editcount INTEGER
27 );
28 CREATE INDEX user_email_token_idx ON user (user_email_token);
29 --leonsp:
30 CREATE UNIQUE INDEX user_include_idx
31 ON user(user_id)
32 INCLUDE (user_name, user_real_name, user_password, user_newpassword, user_newpass_time, user_token,
33 user_email, user_email_token, user_email_token_expires, user_email_authenticated,
34 user_touched, user_registration, user_editcount);
35
36 -- Create a dummy user to satisfy fk contraints especially with revisions
37 INSERT INTO user(
38 user_name, user_real_name, user_password, user_newpassword, user_newpass_time,
39 user_email, user_email_authenticated, user_options, user_token, user_registration, user_editcount)
40 VALUES (
41 'Anonymous','', NULL, NULL, CURRENT_TIMESTAMP,
42 NULL, NULL, NULL, NULL, CURRENT_timestamp, 0);
43
44
45 CREATE TABLE user_groups (
46 ug_user INTEGER NOT NULL DEFAULT 0,
47 -- REFERENCES user(user_id) ON DELETE CASCADE,
48 ug_group VARCHAR(255) NOT NULL
49 );
50 CREATE UNIQUE INDEX user_groups_unique ON user_groups (ug_user, ug_group);
51 --leonsp:
52 CREATE UNIQUE INDEX user_groups_include_idx
53 ON user_groups(ug_user)
54 INCLUDE (ug_group);
55
56
57 CREATE TABLE user_newtalk (
58 -- registered users key
59 user_id INTEGER NOT NULL DEFAULT 0,
60 -- REFERENCES user(user_id) ON DELETE CASCADE,
61 -- anonymous users key
62 user_ip VARCHAR(40),
63 user_last_timestamp TIMESTAMP(3)
64 );
65 CREATE INDEX user_newtalk_id_idx ON user_newtalk (user_id);
66 CREATE INDEX user_newtalk_ip_idx ON user_newtalk (user_ip);
67 --leonsp:
68 CREATE UNIQUE INDEX user_newtalk_include_idx
69 ON user_newtalk(user_id, user_ip)
70 INCLUDE (user_last_timestamp);
71
72
73 CREATE TABLE page (
74 page_id INTEGER PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 0),
75 page_namespace SMALLINT NOT NULL,
76 page_title VARCHAR(255) NOT NULL,
77 page_restrictions VARCHAR(1024),
78 page_counter BIGINT NOT NULL DEFAULT 0,
79 page_is_redirect SMALLINT NOT NULL DEFAULT 0,
80 page_is_new SMALLINT NOT NULL DEFAULT 0,
81 page_random NUMERIC(15,14) NOT NULL,
82 page_touched TIMESTAMP(3),
83 page_latest INTEGER NOT NULL, -- FK?
84 page_len INTEGER NOT NULL
85 );
86 CREATE UNIQUE INDEX page_unique_name ON page (page_namespace, page_title);
87 CREATE INDEX page_random_idx ON page (page_random);
88 CREATE INDEX page_len_idx ON page (page_len);
89 --leonsp:
90 CREATE UNIQUE INDEX page_id_include
91 ON page (page_id)
92 INCLUDE (page_namespace, page_title, page_restrictions, page_counter, page_is_redirect, page_is_new, page_random, page_touched, page_latest, page_len);
93 CREATE UNIQUE INDEX page_name_include
94 ON page (page_namespace, page_title)
95 INCLUDE (page_id, page_restrictions, page_counter, page_is_redirect, page_is_new, page_random, page_touched, page_latest, page_len);
96
97
98 CREATE TABLE revision (
99 rev_id INTEGER PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 0),
100 rev_page INTEGER NOT NULL DEFAULT 0,
101 -- REFERENCES page (page_id) ON DELETE CASCADE,
102 rev_text_id INTEGER, -- FK
103 rev_comment VARCHAR(1024),
104 rev_user INTEGER NOT NULL DEFAULT 0,
105 -- REFERENCES user(user_id) ON DELETE RESTRICT,
106 rev_user_text VARCHAR(255) NOT NULL,
107 rev_timestamp TIMESTAMP(3) NOT NULL,
108 rev_minor_edit SMALLINT NOT NULL DEFAULT 0,
109 rev_deleted SMALLINT NOT NULL DEFAULT 0,
110 rev_len INTEGER,
111 rev_parent_id INTEGER
112 );
113 CREATE UNIQUE INDEX revision_unique ON revision (rev_page, rev_id);
114 CREATE INDEX rev_text_id_idx ON revision (rev_text_id);
115 CREATE INDEX rev_timestamp_idx ON revision (rev_timestamp);
116 CREATE INDEX rev_user_idx ON revision (rev_user);
117 CREATE INDEX rev_user_text_idx ON revision (rev_user_text);
118
119
120
121 CREATE TABLE text ( -- replaces reserved word 'text'
122 --old_id INTEGER NOT NULL,
123 old_id INTEGER PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 0),
124 --PRIMARY KEY DEFAULT nextval('text_old_id_val'),
125 old_text CLOB(16M) INLINE LENGTH 4096,
126 old_flags VARCHAR(1024)
127 );
128
129
130 CREATE TABLE page_restrictions (
131 --pr_id INTEGER NOT NULL UNIQUE, --DEFAULT nextval('pr_id_val'),
132 --pr_id INTEGER PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 0),
133 pr_id INTEGER PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 0),
134 pr_page INTEGER NOT NULL DEFAULT 0,
135 --(used to be nullable)
136 -- REFERENCES page (page_id) ON DELETE CASCADE,
137 pr_type VARCHAR(60) NOT NULL,
138 pr_level VARCHAR(60) NOT NULL,
139 pr_cascade SMALLINT NOT NULL,
140 pr_user INTEGER,
141 pr_expiry TIMESTAMP(3)
142 --PRIMARY KEY (pr_page, pr_type)
143 );
144 --ALTER TABLE page_restrictions ADD CONSTRAINT page_restrictions_pk PRIMARY KEY (pr_page,pr_type);
145 CREATE UNIQUE INDEX pr_pagetype ON page_restrictions (pr_page,pr_type);
146 CREATE INDEX pr_typelevel ON page_restrictions (pr_type,pr_level);
147 CREATE INDEX pr_level ON page_restrictions (pr_level);
148 CREATE INDEX pr_cascade ON page_restrictions (pr_cascade);
149
150 CREATE TABLE page_props (
151 pp_page INTEGER NOT NULL DEFAULT 0,
152 -- REFERENCES page (page_id) ON DELETE CASCADE,
153 pp_propname VARCHAR(255) NOT NULL,
154 pp_value CLOB(64K) INLINE LENGTH 4096 NOT NULL,
155 PRIMARY KEY (pp_page,pp_propname)
156 );
157 --ALTER TABLE page_props ADD CONSTRAINT page_props_pk PRIMARY KEY (pp_page,pp_propname);
158 CREATE INDEX page_props_propname ON page_props (pp_propname);
159
160
161
162 CREATE TABLE archive (
163 ar_namespace SMALLINT NOT NULL,
164 ar_title VARCHAR(255) NOT NULL,
165 ar_text CLOB(16M) INLINE LENGTH 4096,
166 ar_comment VARCHAR(1024),
167 ar_user INTEGER NOT NULL,
168 -- no foreign keys in MySQL
169 -- REFERENCES user(user_id) ON DELETE SET NULL,
170 ar_user_text VARCHAR(255) NOT NULL,
171 ar_timestamp TIMESTAMP(3) NOT NULL,
172 ar_minor_edit SMALLINT NOT NULL DEFAULT 0,
173 ar_flags VARCHAR(1024),
174 ar_rev_id INTEGER,
175 ar_text_id INTEGER,
176 ar_deleted SMALLINT NOT NULL DEFAULT 0,
177 ar_len INTEGER,
178 ar_page_id INTEGER,
179 ar_parent_id INTEGER
180 );
181 CREATE INDEX archive_name_title_timestamp ON archive (ar_namespace,ar_title,ar_timestamp);
182 CREATE INDEX archive_user_text ON archive (ar_user_text);
183
184
185
186 CREATE TABLE redirect (
187 rd_from INTEGER NOT NULL PRIMARY KEY,
188 --REFERENCES page(page_id) ON DELETE CASCADE,
189 rd_namespace SMALLINT NOT NULL DEFAULT 0,
190 rd_title VARCHAR(255) NOT NULL DEFAULT '',
191 rd_interwiki varchar(32),
192 rd_fragment VARCHAR(255)
193 );
194 CREATE INDEX redirect_ns_title ON redirect (rd_namespace,rd_title,rd_from);
195
196
197 CREATE TABLE pagelinks (
198 pl_from INTEGER NOT NULL DEFAULT 0,
199 -- REFERENCES page(page_id) ON DELETE CASCADE,
200 pl_namespace SMALLINT NOT NULL,
201 pl_title VARCHAR(255) NOT NULL
202 );
203 CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_from,pl_namespace,pl_title);
204
205 CREATE TABLE templatelinks (
206 tl_from INTEGER NOT NULL DEFAULT 0,
207 -- REFERENCES page(page_id) ON DELETE CASCADE,
208 tl_namespace SMALLINT NOT NULL,
209 tl_title VARCHAR(255) NOT NULL
210 );
211 CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from);
212 CREATE UNIQUE INDEX tl_from_idx ON templatelinks (tl_from,tl_namespace,tl_title);
213
214 CREATE TABLE imagelinks (
215 il_from INTEGER NOT NULL DEFAULT 0,
216 -- REFERENCES page(page_id) ON DELETE CASCADE,
217 il_to VARCHAR(255) NOT NULL
218 );
219 CREATE UNIQUE INDEX il_from_idx ON imagelinks (il_to,il_from);
220 CREATE UNIQUE INDEX il_to_idx ON imagelinks (il_from,il_to);
221
222 CREATE TABLE categorylinks (
223 cl_from INTEGER NOT NULL DEFAULT 0,
224 -- REFERENCES page(page_id) ON DELETE CASCADE,
225 cl_to VARCHAR(255) NOT NULL,
226 cl_sortkey VARCHAR(70),
227 cl_timestamp TIMESTAMP(3) NOT NULL
228 );
229 CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to);
230 CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey, cl_from);
231
232
233
234 CREATE TABLE externallinks (
235 el_from INTEGER NOT NULL DEFAULT 0,
236 -- REFERENCES page(page_id) ON DELETE CASCADE,
237 el_to VARCHAR(1024) NOT NULL,
238 el_index VARCHAR(1024) NOT NULL
239 );
240 CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to);
241 CREATE INDEX externallinks_index ON externallinks (el_index);
242
243
244 --
245 -- Track external user accounts, if ExternalAuth is used
246 --
247 CREATE TABLE external_user (
248 -- Foreign key to user_id
249 eu_wiki_id INTEGER NOT NULL PRIMARY KEY,
250
251 -- Some opaque identifier provided by the external database
252 eu_external_id VARCHAR(255) NOT NULL
253 );
254 CREATE UNIQUE INDEX eu_external_id_idx
255 ON external_user (eu_external_id)
256 INCLUDE (eu_wiki_id);
257 CREATE UNIQUE INDEX eu_wiki_id_idx
258 ON external_user (eu_wiki_id)
259 INCLUDE (eu_external_id);
260
261
262
263 CREATE TABLE langlinks (
264 ll_from INTEGER NOT NULL DEFAULT 0,
265 -- REFERENCES page (page_id) ON DELETE CASCADE,
266 ll_lang VARCHAR(20),
267 ll_title VARCHAR(255)
268 );
269 CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang);
270 CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title);
271
272
273 CREATE TABLE site_stats (
274 ss_row_id INTEGER NOT NULL UNIQUE,
275 ss_total_views INTEGER DEFAULT 0,
276 ss_total_edits INTEGER DEFAULT 0,
277 ss_good_articles INTEGER DEFAULT 0,
278 ss_total_pages INTEGER DEFAULT -1,
279 ss_users INTEGER DEFAULT -1,
280 ss_active_users INTEGER DEFAULT -1,
281 ss_admins INTEGER DEFAULT -1,
282 ss_images INTEGER DEFAULT 0
283 );
284
285 CREATE TABLE hitcounter (
286 hc_id BIGINT NOT NULL
287 );
288
289 CREATE TABLE ipblocks (
290 ipb_id INTEGER NOT NULL PRIMARY KEY,
291 --DEFAULT nextval('ipblocks_ipb_id_val'),
292 ipb_address VARCHAR(1024),
293 ipb_user INTEGER NOT NULL DEFAULT 0,
294 -- REFERENCES user(user_id) ON DELETE SET NULL,
295 ipb_by INTEGER NOT NULL DEFAULT 0,
296 -- REFERENCES user(user_id) ON DELETE CASCADE,
297 ipb_by_text VARCHAR(255) NOT NULL DEFAULT '',
298 ipb_reason VARCHAR(1024) NOT NULL,
299 ipb_timestamp TIMESTAMP(3) NOT NULL,
300 ipb_auto SMALLINT NOT NULL DEFAULT 0,
301 ipb_anon_only SMALLINT NOT NULL DEFAULT 0,
302 ipb_create_account SMALLINT NOT NULL DEFAULT 1,
303 ipb_enable_autoblock SMALLINT NOT NULL DEFAULT 1,
304 ipb_expiry TIMESTAMP(3) NOT NULL,
305 ipb_range_start VARCHAR(1024),
306 ipb_range_end VARCHAR(1024),
307 ipb_deleted SMALLINT NOT NULL DEFAULT 0,
308 ipb_block_email SMALLINT NOT NULL DEFAULT 0,
309 ipb_allow_usertalk SMALLINT NOT NULL DEFAULT 0
310
311 );
312 CREATE INDEX ipb_address ON ipblocks (ipb_address);
313 CREATE INDEX ipb_user ON ipblocks (ipb_user);
314 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
315
316
317
318 CREATE TABLE image (
319 img_name VARCHAR(255) NOT NULL PRIMARY KEY,
320 img_size INTEGER NOT NULL,
321 img_width INTEGER NOT NULL,
322 img_height INTEGER NOT NULL,
323 img_metadata CLOB(16M) INLINE LENGTH 4096 NOT NULL DEFAULT '',
324 img_bits SMALLINT,
325 img_media_type VARCHAR(255),
326 img_major_mime VARCHAR(255) DEFAULT 'unknown',
327 img_minor_mime VARCHAR(32) DEFAULT 'unknown',
328 img_description VARCHAR(1024) NOT NULL DEFAULT '',
329 img_user INTEGER NOT NULL DEFAULT 0,
330 -- REFERENCES user(user_id) ON DELETE SET NULL,
331 img_user_text VARCHAR(255) NOT NULL DEFAULT '',
332 img_timestamp TIMESTAMP(3),
333 img_sha1 VARCHAR(255) NOT NULL DEFAULT ''
334 );
335 CREATE INDEX img_size_idx ON image (img_size);
336 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
337 CREATE INDEX img_sha1 ON image (img_sha1);
338
339 CREATE TABLE oldimage (
340 oi_name VARCHAR(255) NOT NULL DEFAULT '',
341 oi_archive_name VARCHAR(255) NOT NULL,
342 oi_size INTEGER NOT NULL,
343 oi_width INTEGER NOT NULL,
344 oi_height INTEGER NOT NULL,
345 oi_bits SMALLINT NOT NULL,
346 oi_description VARCHAR(1024),
347 oi_user INTEGER NOT NULL DEFAULT 0,
348 -- REFERENCES user(user_id) ON DELETE SET NULL,
349 oi_user_text VARCHAR(255) NOT NULL,
350 oi_timestamp TIMESTAMP(3) NOT NULL,
351 oi_metadata CLOB(16M) INLINE LENGTH 4096 NOT NULL DEFAULT '',
352 oi_media_type VARCHAR(255) ,
353 oi_major_mime VARCHAR(255) NOT NULL DEFAULT 'unknown',
354 oi_minor_mime VARCHAR(255) NOT NULL DEFAULT 'unknown',
355 oi_deleted SMALLINT NOT NULL DEFAULT 0,
356 oi_sha1 VARCHAR(255) NOT NULL DEFAULT ''
357 --FOREIGN KEY (oi_name) REFERENCES image(img_name) ON DELETE CASCADE
358 );
359 --ALTER TABLE oldimage ADD CONSTRAINT oldimage_oi_name_fkey_cascade FOREIGN KEY (oi_name) REFERENCES image(img_name) ON DELETE CASCADE;
360 CREATE INDEX oi_name_timestamp ON oldimage (oi_name,oi_timestamp);
361 CREATE INDEX oi_name_archive_name ON oldimage (oi_name,oi_archive_name);
362 CREATE INDEX oi_sha1 ON oldimage (oi_sha1);
363
364
365
366 CREATE TABLE filearchive (
367 fa_id INTEGER NOT NULL PRIMARY KEY,
368 --PRIMARY KEY DEFAULT nextval('filearchive_fa_id_seq'),
369 fa_name VARCHAR(255) NOT NULL,
370 fa_archive_name VARCHAR(255),
371 fa_storage_group VARCHAR(255),
372 fa_storage_key VARCHAR(32),
373 fa_deleted_user INTEGER NOT NULL DEFAULT 0,
374 -- REFERENCES user(user_id) ON DELETE SET NULL,
375 fa_deleted_timestamp TIMESTAMP(3) NOT NULL,
376 fa_deleted_reason VARCHAR(255),
377 fa_size INTEGER NOT NULL,
378 fa_width INTEGER NOT NULL,
379 fa_height INTEGER NOT NULL,
380 fa_metadata CLOB(16M) INLINE LENGTH 4096 NOT NULL DEFAULT '',
381 fa_bits SMALLINT,
382 fa_media_type VARCHAR(255),
383 fa_major_mime VARCHAR(255) DEFAULT 'unknown',
384 fa_minor_mime VARCHAR(255) DEFAULT 'unknown',
385 fa_description VARCHAR(1024) NOT NULL,
386 fa_user INTEGER NOT NULL DEFAULT 0,
387 -- REFERENCES user(user_id) ON DELETE SET NULL,
388 fa_user_text VARCHAR(255) NOT NULL,
389 fa_timestamp TIMESTAMP(3),
390 fa_deleted SMALLINT NOT NULL DEFAULT 0
391 );
392 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
393 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
394 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
395 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
396
397
398 CREATE TABLE recentchanges (
399 rc_id INTEGER NOT NULL PRIMARY KEY,
400 --PRIMARY KEY DEFAULT nextval('rc_rc_id_seq'),
401 rc_timestamp TIMESTAMP(3) NOT NULL,
402 rc_cur_time TIMESTAMP(3) NOT NULL,
403 rc_user INTEGER NOT NULL DEFAULT 0,
404 -- REFERENCES user(user_id) ON DELETE SET NULL,
405 rc_user_text VARCHAR(255) NOT NULL,
406 rc_namespace SMALLINT NOT NULL,
407 rc_title VARCHAR(255) NOT NULL,
408 rc_comment VARCHAR(255),
409 rc_minor SMALLINT NOT NULL DEFAULT 0,
410 rc_bot SMALLINT NOT NULL DEFAULT 0,
411 rc_new SMALLINT NOT NULL DEFAULT 0,
412 rc_cur_id INTEGER NOT NULL DEFAULT 0,
413 -- REFERENCES page(page_id) ON DELETE SET NULL,
414 rc_this_oldid INTEGER NOT NULL,
415 rc_last_oldid INTEGER NOT NULL,
416 rc_type SMALLINT NOT NULL DEFAULT 0,
417 rc_moved_to_ns SMALLINT,
418 rc_moved_to_title VARCHAR(255),
419 rc_patrolled SMALLINT NOT NULL DEFAULT 0,
420 rc_ip VARCHAR(40), -- was CIDR type
421 rc_old_len INTEGER,
422 rc_new_len INTEGER,
423 rc_deleted SMALLINT NOT NULL DEFAULT 0,
424 rc_logid INTEGER NOT NULL DEFAULT 0,
425 rc_log_type VARCHAR(255),
426 rc_log_action VARCHAR(255),
427 rc_params CLOB(64K) INLINE LENGTH 4096
428
429 );
430 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
431 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
432 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
433 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
434 CREATE INDEX rc_ip ON recentchanges (rc_ip);
435
436
437
438 CREATE TABLE watchlist (
439 wl_user INTEGER NOT NULL DEFAULT 0,
440 -- REFERENCES user(user_id) ON DELETE CASCADE,
441 wl_namespace SMALLINT NOT NULL DEFAULT 0,
442 wl_title VARCHAR(255) NOT NULL,
443 wl_notificationtimestamp TIMESTAMP(3)
444 );
445 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
446
447
448 CREATE TABLE math (
449 math_inputhash VARCHAR(16) FOR BIT DATA NOT NULL UNIQUE,
450 math_outputhash VARCHAR(16) FOR BIT DATA NOT NULL,
451 math_html_conservativeness SMALLINT NOT NULL,
452 math_html CLOB(64K) INLINE LENGTH 4096,
453 math_mathml CLOB(64K) INLINE LENGTH 4096
454 );
455
456
457 CREATE TABLE interwiki (
458 iw_prefix VARCHAR(32) NOT NULL UNIQUE,
459 iw_url CLOB(64K) INLINE LENGTH 4096 NOT NULL,
460 iw_local SMALLINT NOT NULL,
461 iw_trans SMALLINT NOT NULL DEFAULT 0
462 );
463
464
465 CREATE TABLE querycache (
466 qc_type VARCHAR(255) NOT NULL,
467 qc_value INTEGER NOT NULL,
468 qc_namespace SMALLINT NOT NULL,
469 qc_title VARCHAR(255) NOT NULL
470 );
471 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
472
473
474
475 CREATE TABLE querycache_info (
476 qci_type VARCHAR(255) UNIQUE NOT NULL,
477 qci_timestamp TIMESTAMP(3)
478 );
479
480
481 CREATE TABLE querycachetwo (
482 qcc_type VARCHAR(255) NOT NULL,
483 qcc_value INTEGER NOT NULL DEFAULT 0,
484 qcc_namespace INTEGER NOT NULL DEFAULT 0,
485 qcc_title VARCHAR(255) NOT NULL DEFAULT '',
486 qcc_namespacetwo INTEGER NOT NULL DEFAULT 0,
487 qcc_titletwo VARCHAR(255) NOT NULL DEFAULT ''
488 );
489 CREATE INDEX querycachetwo_type_value ON querycachetwo (qcc_type, qcc_value);
490 CREATE INDEX querycachetwo_title ON querycachetwo (qcc_type,qcc_namespace,qcc_title);
491 CREATE INDEX querycachetwo_titletwo ON querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
492
493 CREATE TABLE objectcache (
494 keyname VARCHAR(255) NOT NULL UNIQUE, -- was nullable
495 value CLOB(16M) INLINE LENGTH 4096 NOT NULL DEFAULT '',
496 exptime TIMESTAMP(3) NOT NULL
497 );
498 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
499
500
501
502 CREATE TABLE transcache (
503 tc_url VARCHAR(255) NOT NULL UNIQUE,
504 tc_contents VARCHAR(255) NOT NULL,
505 tc_time TIMESTAMP(3) NOT NULL
506 );
507
508
509 CREATE TABLE logging (
510 log_id INTEGER NOT NULL PRIMARY KEY,
511 --PRIMARY KEY DEFAULT nextval('log_log_id_seq'),
512 log_type VARCHAR(32) NOT NULL,
513 log_action VARCHAR(32) NOT NULL,
514 log_timestamp TIMESTAMP(3) NOT NULL,
515 log_user INTEGER NOT NULL DEFAULT 0,
516 -- REFERENCES user(user_id) ON DELETE SET NULL,
517 -- Name of the user who performed this action
518 log_user_text VARCHAR(255) NOT NULL default '',
519 log_namespace SMALLINT NOT NULL,
520 log_title VARCHAR(255) NOT NULL,
521 log_page INTEGER,
522 log_comment VARCHAR(255),
523 log_params CLOB(64K) INLINE LENGTH 4096,
524 log_deleted SMALLINT NOT NULL DEFAULT 0
525 );
526 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
527 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
528 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
529 CREATE INDEX log_user_type_time ON logging (log_user, log_type, log_timestamp);
530 CREATE INDEX log_page_id_time ON logging (log_page,log_timestamp);
531
532
533
534 CREATE TABLE trackbacks (
535 tb_id INTEGER NOT NULL PRIMARY KEY,
536 --PRIMARY KEY DEFAULT nextval('trackbacks_tb_id_seq'),
537 -- foreign key also in MySQL
538 tb_page INTEGER REFERENCES page(page_id) ON DELETE CASCADE,
539 tb_title VARCHAR(255) NOT NULL,
540 tb_url CLOB(64K) INLINE LENGTH 4096 NOT NULL,
541 tb_ex CLOB(64K) INLINE LENGTH 4096,
542 tb_name VARCHAR(255)
543 );
544 CREATE INDEX trackback_page ON trackbacks (tb_page);
545
546
547
548 CREATE TABLE job (
549 job_id INTEGER NOT NULL PRIMARY KEY,
550 --PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
551 job_cmd VARCHAR(255) NOT NULL,
552 job_namespace SMALLINT NOT NULL,
553 job_title VARCHAR(255) NOT NULL,
554 job_params CLOB(64K) INLINE LENGTH 4096 NOT NULL
555 );
556 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
557
558
559
560 -- Postgres' Tsearch2 dropped
561 --ALTER TABLE page ADD titlevector tsvector;
562 --CREATE FUNCTION ts2_page_title() RETURNS TRIGGER LANGUAGE plpgsql AS
563 --$mw$
564 --BEGIN
565 --IF TG_OP = 'INSERT' THEN
566 -- NEW.titlevector = to_tsvector('default',REPLACE(NEW.page_title,'/',' '));
567 --ELSIF NEW.page_title != OLD.page_title THEN
568 -- NEW.titlevector := to_tsvector('default',REPLACE(NEW.page_title,'/',' '));
569 --END IF;
570 --RETURN NEW;
571 --END;
572 --$mw$;
573
574 --CREATE TRIGGER ts2_page_title BEFORE INSERT OR UPDATE ON page
575 -- FOR EACH ROW EXECUTE PROCEDURE ts2_page_title();
576
577
578 --ALTER TABLE text ADD textvector tsvector;
579 --CREATE FUNCTION ts2_page_text() RETURNS TRIGGER LANGUAGE plpgsql AS
580 --$mw$
581 --BEGIN
582 --IF TG_OP = 'INSERT' THEN
583 -- NEW.textvector = to_tsvector('default',NEW.old_text);
584 --ELSIF NEW.old_text != OLD.old_text THEN
585 -- NEW.textvector := to_tsvector('default',NEW.old_text);
586 --END IF;
587 --RETURN NEW;
588 --END;
589 --$mw$;
590
591 --CREATE TRIGGER ts2_page_text BEFORE INSERT OR UPDATE ON text
592 -- FOR EACH ROW EXECUTE PROCEDURE ts2_page_text();
593
594 -- These are added by the setup script due to version compatibility issues
595 -- If using 8.1, we switch from "gin" to "gist"
596
597 --CREATE INDEX ts2_page_title ON page USING gin(titlevector);
598 --CREATE INDEX ts2_page_text ON text USING gin(textvector);
599
600 --TODO
601 --CREATE FUNCTION add_interwiki (TEXT,INT,SMALLINT) RETURNS INT LANGUAGE SQL AS
602 --$mw$
603 -- INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
604 -- SELECT 1;
605 --$mw$;
606
607 -- hack implementation
608 -- should be replaced with OmniFind, Contains(), etc
609 CREATE TABLE searchindex (
610 si_page int NOT NULL,
611 si_title varchar(255) NOT NULL default '',
612 si_text clob NOT NULL
613 );
614
615 -- This table is not used unless profiling is turned on
616 CREATE TABLE profiling (
617 pf_count INTEGER NOT NULL DEFAULT 0,
618 pf_time NUMERIC(18,10) NOT NULL DEFAULT 0,
619 pf_memory NUMERIC(18,10) NOT NULL DEFAULT 0,
620 pf_name VARCHAR(255) NOT NULL,
621 pf_server VARCHAR(255)
622 );
623 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
624
625 CREATE TABLE protected_titles (
626 pt_namespace SMALLINT NOT NULL,
627 pt_title VARCHAR(255) NOT NULL,
628 pt_user INTEGER NOT NULL DEFAULT 0,
629 -- REFERENCES user(user_id) ON DELETE SET NULL,
630 pt_reason VARCHAR(1024),
631 pt_timestamp TIMESTAMP(3) NOT NULL,
632 pt_expiry TIMESTAMP(3) ,
633 pt_create_perm VARCHAR(60) NOT NULL DEFAULT ''
634 );
635 CREATE UNIQUE INDEX protected_titles_unique ON protected_titles(pt_namespace, pt_title);
636
637
638
639 CREATE TABLE updatelog (
640 ul_key VARCHAR(255) NOT NULL PRIMARY KEY
641 );
642
643
644 CREATE TABLE category (
645 cat_id INTEGER NOT NULL PRIMARY KEY,
646 --PRIMARY KEY DEFAULT nextval('category_id_seq'),
647 cat_title VARCHAR(255) NOT NULL,
648 cat_pages INTEGER NOT NULL DEFAULT 0,
649 cat_subcats INTEGER NOT NULL DEFAULT 0,
650 cat_files INTEGER NOT NULL DEFAULT 0,
651 cat_hidden SMALLINT NOT NULL DEFAULT 0
652 );
653 CREATE UNIQUE INDEX category_title ON category(cat_title);
654 CREATE INDEX category_pages ON category(cat_pages);
655
656 -- added for 1.15
657
658 -- A table to track tags for revisions, logs and recent changes.
659 CREATE TABLE change_tag (
660 ct_rc_id INTEGER,
661 ct_log_id INTEGER,
662 ct_rev_id INTEGER,
663 ct_tag varchar(255) NOT NULL,
664 ct_params CLOB(64K) INLINE LENGTH 4096
665 );
666 CREATE UNIQUE INDEX change_tag_rc_tag ON change_tag (ct_rc_id,ct_tag);
667 CREATE UNIQUE INDEX change_tag_log_tag ON change_tag (ct_log_id,ct_tag);
668 CREATE UNIQUE INDEX change_tag_rev_tag ON change_tag (ct_rev_id,ct_tag);
669 -- Covering index, so we can pull all the info only out of the index.
670 CREATE INDEX change_tag_tag_id ON change_tag (ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
671
672
673 -- Rollup table to pull a LIST of tags simply
674 CREATE TABLE tag_summary (
675 ts_rc_id INTEGER,
676 ts_log_id INTEGER,
677 ts_rev_id INTEGER,
678 ts_tags CLOB(64K) INLINE LENGTH 4096 NOT NULL
679 );
680 CREATE UNIQUE INDEX tag_summary_rc_id ON tag_summary (ts_rc_id);
681 CREATE UNIQUE INDEX tag_summary_log_id ON tag_summary (ts_log_id);
682 CREATE UNIQUE INDEX tag_summary_rev_id ON tag_summary (ts_rev_id);
683
684
685 CREATE TABLE valid_tag (
686 vt_tag varchar(255) NOT NULL PRIMARY KEY
687 );
688
689 --
690 -- User preferences and perhaps other fun stuff. :)
691 -- Replaces the old user.user_options blob, with a couple nice properties:
692 --
693 -- 1) We only store non-default settings, so changes to the defaults
694 -- are now reflected for everybody, not just new accounts.
695 -- 2) We can more easily do bulk lookups, statistics, or modifications of
696 -- saved options since it's a sane table structure.
697 --
698 CREATE TABLE user_properties (
699 -- Foreign key to user.user_id
700 up_user INTEGER NOT NULL,
701
702 -- Name of the option being saved. This is indexed for bulk lookup.
703 up_property VARCHAR(32) FOR BIT DATA NOT NULL,
704
705 -- Property value as a string.
706 up_value CLOB(64K) INLINE LENGTH 4096
707 );
708 CREATE UNIQUE INDEX user_properties_user_property ON user_properties (up_user,up_property);
709 CREATE INDEX user_properties_property ON user_properties (up_property);
710
711 CREATE TABLE log_search (
712 -- The type of ID (rev ID, log ID, rev TIMESTAMP(3), username)
713 ls_field VARCHAR(32) FOR BIT DATA NOT NULL,
714 -- The value of the ID
715 ls_value varchar(255) NOT NULL,
716 -- Key to log_id
717 ls_log_id INTEGER NOT NULL default 0
718 );
719 CREATE UNIQUE INDEX ls_field_val ON log_search (ls_field,ls_value,ls_log_id);
720 CREATE INDEX ls_log_id ON log_search (ls_log_id);
721
722 CREATE TABLE mediawiki_version (
723 type VARCHAR(1024) NOT NULL,
724 mw_version VARCHAR(1024) NOT NULL,
725 notes VARCHAR(1024) ,
726
727 pg_version VARCHAR(1024) ,
728 pg_dbname VARCHAR(1024) ,
729 pg_user VARCHAR(1024) ,
730 pg_port VARCHAR(1024) ,
731 mw_schema VARCHAR(1024) ,
732 ts2_schema VARCHAR(1024) ,
733 ctype VARCHAR(1024) ,
734
735 sql_version VARCHAR(1024) ,
736 sql_date VARCHAR(1024) ,
737 cdate TIMESTAMP(3) NOT NULL DEFAULT CURRENT TIMESTAMP
738 );
739
740 INSERT INTO mediawiki_version (type,mw_version,sql_version,sql_date)
741 VALUES ('Creation','??','$LastChangedRevision: 34049 $','$LastChangedDate: 2008-04-30 10:20:36 -0400 (Wed, 30 Apr 2008) $');
742
743 -- Table for storing localisation data
744 CREATE TABLE l10n_cache (
745 -- Language code
746 lc_lang VARCHAR(32) NOT NULL,
747 -- Cache key
748 lc_key VARCHAR(255) NOT NULL,
749 -- Value
750 lc_value CLOB(16M) INLINE LENGTH 4096 NOT NULL
751 );
752 CREATE INDEX lc_lang_key ON l10n_cache (lc_lang, lc_key);
753