af04e64e9b3795f80cb18cdb6d0609ad48e0e371
[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 -- Needs to start with 0
12 user_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 0),
13 user_name VARCHAR(255) NOT NULL UNIQUE,
14 user_real_name VARCHAR(255),
15 user_password VARCHAR(1024),
16 user_newpassword VARCHAR(1024),
17 user_newpass_time TIMESTAMP(3),
18 user_token VARCHAR(255),
19 user_email VARCHAR(1024),
20 user_email_token VARCHAR(255),
21 user_email_token_expires TIMESTAMP(3),
22 user_email_authenticated TIMESTAMP(3),
23 -- obsolete, replace by user_properties table
24 user_options CLOB(64K) INLINE LENGTH 4096,
25 user_touched TIMESTAMP(3),
26 user_registration TIMESTAMP(3),
27 user_editcount INTEGER
28 );
29 CREATE INDEX user_email_token_idx ON user (user_email_token);
30 --leonsp:
31 CREATE UNIQUE INDEX user_include_idx
32 ON user(user_id)
33 INCLUDE (user_name, user_real_name, user_password, user_newpassword, user_newpass_time, user_token,
34 user_email, user_email_token, user_email_token_expires, user_email_authenticated,
35 user_touched, user_registration, user_editcount);
36
37 -- Create a dummy user to satisfy fk contraints especially with revisions
38 INSERT INTO user(
39 user_name, user_real_name, user_password, user_newpassword, user_newpass_time,
40 user_email, user_email_authenticated, user_options, user_token, user_registration, user_editcount)
41 VALUES (
42 'Anonymous','', NULL, NULL, CURRENT_TIMESTAMP,
43 NULL, NULL, NULL, NULL, CURRENT_timestamp, 0);
44
45
46 CREATE TABLE user_groups (
47 ug_user BIGINT NOT NULL DEFAULT 0,
48 -- REFERENCES user(user_id) ON DELETE CASCADE,
49 ug_group VARCHAR(255) NOT NULL
50 );
51 CREATE INDEX user_groups_unique ON user_groups (ug_user, ug_group);
52
53
54 CREATE TABLE user_newtalk (
55 -- registered users key
56 user_id BIGINT NOT NULL DEFAULT 0,
57 -- REFERENCES user(user_id) ON DELETE CASCADE,
58 -- anonymous users key
59 user_ip VARCHAR(40),
60 user_last_timestamp TIMESTAMP(3)
61 );
62 CREATE INDEX user_newtalk_id_idx ON user_newtalk (user_id);
63 CREATE INDEX user_newtalk_ip_idx ON user_newtalk (user_ip);
64 --leonsp:
65 CREATE UNIQUE INDEX user_newtalk_include_idx
66 ON user_newtalk(user_id, user_ip)
67 INCLUDE (user_last_timestamp);
68
69
70 CREATE TABLE page (
71 page_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
72 page_namespace SMALLINT NOT NULL,
73 page_title VARCHAR(255) NOT NULL,
74 page_restrictions VARCHAR(1024),
75 page_counter BIGINT NOT NULL DEFAULT 0,
76 page_is_redirect SMALLINT NOT NULL DEFAULT 0,
77 page_is_new SMALLINT NOT NULL DEFAULT 0,
78 page_random NUMERIC(15,14) NOT NULL,
79 page_touched TIMESTAMP(3),
80 page_latest BIGINT NOT NULL, -- FK?
81 page_len BIGINT NOT NULL
82 );
83 CREATE UNIQUE INDEX page_unique_name ON page (page_namespace, page_title);
84 CREATE INDEX page_random_idx ON page (page_random);
85 CREATE INDEX page_len_idx ON page (page_len);
86 --leonsp:
87 CREATE UNIQUE INDEX page_id_include
88 ON page (page_id)
89 INCLUDE (page_namespace, page_title, page_restrictions, page_counter, page_is_redirect, page_is_new, page_random, page_touched, page_latest, page_len);
90 CREATE UNIQUE INDEX page_name_include
91 ON page (page_namespace, page_title)
92 INCLUDE (page_id, page_restrictions, page_counter, page_is_redirect, page_is_new, page_random, page_touched, page_latest, page_len);
93
94
95 CREATE TABLE revision (
96 rev_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
97 rev_page BIGINT NOT NULL DEFAULT 0,
98 -- REFERENCES page (page_id) ON DELETE CASCADE,
99 rev_text_id BIGINT, -- FK
100 rev_comment VARCHAR(1024),
101 rev_user BIGINT NOT NULL DEFAULT 0,
102 -- REFERENCES user(user_id) ON DELETE RESTRICT,
103 rev_user_text VARCHAR(255) NOT NULL,
104 rev_timestamp TIMESTAMP(3) NOT NULL,
105 rev_minor_edit SMALLINT NOT NULL DEFAULT 0,
106 rev_deleted SMALLINT NOT NULL DEFAULT 0,
107 rev_len BIGINT,
108 rev_parent_id BIGINT DEFAULT NULL
109 );
110 CREATE UNIQUE INDEX revision_unique ON revision (rev_page, rev_id);
111 CREATE INDEX rev_text_id_idx ON revision (rev_text_id);
112 CREATE INDEX rev_timestamp_idx ON revision (rev_timestamp);
113 CREATE INDEX rev_user_idx ON revision (rev_user);
114 CREATE INDEX rev_user_text_idx ON revision (rev_user_text);
115
116
117
118 CREATE TABLE text ( -- replaces reserved word 'text'
119 old_id INTEGER PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
120 old_text CLOB(16M) INLINE LENGTH 4096,
121 old_flags VARCHAR(1024)
122 );
123
124
125 CREATE TABLE page_restrictions (
126 --pr_id INTEGER NOT NULL UNIQUE, --DEFAULT nextval('pr_id_val'),
127 --pr_id INTEGER PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
128 pr_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
129 pr_page INTEGER NOT NULL DEFAULT 0,
130 --(used to be nullable)
131 -- REFERENCES page (page_id) ON DELETE CASCADE,
132 pr_type VARCHAR(60) NOT NULL,
133 pr_level VARCHAR(60) NOT NULL,
134 pr_cascade SMALLINT NOT NULL,
135 pr_user INTEGER,
136 pr_expiry TIMESTAMP(3)
137 --PRIMARY KEY (pr_page, pr_type)
138 );
139 --ALTER TABLE page_restrictions ADD CONSTRAINT page_restrictions_pk PRIMARY KEY (pr_page,pr_type);
140 CREATE UNIQUE INDEX pr_pagetype ON page_restrictions (pr_page,pr_type);
141 CREATE INDEX pr_typelevel ON page_restrictions (pr_type,pr_level);
142 CREATE INDEX pr_level ON page_restrictions (pr_level);
143 CREATE INDEX pr_cascade ON page_restrictions (pr_cascade);
144
145 CREATE TABLE page_props (
146 pp_page INTEGER NOT NULL DEFAULT 0,
147 -- REFERENCES page (page_id) ON DELETE CASCADE,
148 pp_propname VARCHAR(255) NOT NULL,
149 pp_value CLOB(64K) INLINE LENGTH 4096 NOT NULL,
150 PRIMARY KEY (pp_page,pp_propname)
151 );
152 --ALTER TABLE page_props ADD CONSTRAINT page_props_pk PRIMARY KEY (pp_page,pp_propname);
153 CREATE INDEX page_props_propname ON page_props (pp_propname);
154
155
156
157 CREATE TABLE archive (
158 ar_namespace SMALLINT NOT NULL,
159 ar_title VARCHAR(255) NOT NULL,
160 ar_text CLOB(16M) INLINE LENGTH 4096,
161 ar_comment VARCHAR(1024),
162 ar_user BIGINT NOT NULL,
163 -- no foreign keys in MySQL
164 -- REFERENCES user(user_id) ON DELETE SET NULL,
165 ar_user_text VARCHAR(255) NOT NULL,
166 ar_timestamp TIMESTAMP(3) NOT NULL,
167 ar_minor_edit SMALLINT NOT NULL DEFAULT 0,
168 ar_flags VARCHAR(1024),
169 ar_rev_id INTEGER,
170 ar_text_id INTEGER,
171 ar_deleted SMALLINT NOT NULL DEFAULT 0,
172 ar_len INTEGER,
173 ar_page_id INTEGER,
174 ar_parent_id INTEGER
175 );
176 CREATE INDEX archive_name_title_timestamp ON archive (ar_namespace,ar_title,ar_timestamp);
177 CREATE INDEX archive_user_text ON archive (ar_user_text);
178
179
180
181 CREATE TABLE redirect (
182 rd_from BIGINT NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
183 --REFERENCES page(page_id) ON DELETE CASCADE,
184 rd_namespace SMALLINT NOT NULL DEFAULT 0,
185 rd_title VARCHAR(255) NOT NULL DEFAULT '',
186 rd_interwiki varchar(32),
187 rd_fragment VARCHAR(255)
188 );
189 CREATE INDEX redirect_ns_title ON redirect (rd_namespace,rd_title,rd_from);
190
191
192 CREATE TABLE pagelinks (
193 pl_from BIGINT NOT NULL DEFAULT 0,
194 -- REFERENCES page(page_id) ON DELETE CASCADE,
195 pl_namespace SMALLINT NOT NULL,
196 pl_title VARCHAR(255) NOT NULL
197 );
198 CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_from,pl_namespace,pl_title);
199
200 CREATE TABLE templatelinks (
201 tl_from BIGINT NOT NULL DEFAULT 0,
202 -- REFERENCES page(page_id) ON DELETE CASCADE,
203 tl_namespace SMALLINT NOT NULL,
204 tl_title VARCHAR(255) NOT NULL
205 );
206 CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from);
207 CREATE UNIQUE INDEX tl_from_idx ON templatelinks (tl_from,tl_namespace,tl_title);
208
209 CREATE TABLE imagelinks (
210 il_from BIGINT NOT NULL DEFAULT 0,
211 -- REFERENCES page(page_id) ON DELETE CASCADE,
212 il_to VARCHAR(255) NOT NULL
213 );
214 CREATE UNIQUE INDEX il_from_idx ON imagelinks (il_to,il_from);
215 CREATE UNIQUE INDEX il_to_idx ON imagelinks (il_from,il_to);
216
217 CREATE TABLE categorylinks (
218 cl_from BIGINT NOT NULL DEFAULT 0,
219 -- REFERENCES page(page_id) ON DELETE CASCADE,
220 cl_to VARCHAR(255) NOT NULL,
221 -- cl_sortkey has to be at least 86 wide
222 -- in order to be compatible with the old MySQL schema from MW 1.10
223 --cl_sortkey VARCHAR(86),
224 cl_sortkey VARCHAR(230) FOR BIT DATA NOT NULL ,
225 cl_sortkey_prefix VARCHAR(255) FOR BIT DATA NOT NULL ,
226 cl_timestamp TIMESTAMP(3) NOT NULL,
227 cl_collation VARCHAR(32) FOR BIT DATA NOT NULL ,
228 cl_type VARCHAR(6) FOR BIT DATA NOT NULL
229 );
230 CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to);
231 CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey, cl_from);
232
233
234
235 CREATE TABLE externallinks (
236 el_from BIGINT NOT NULL DEFAULT 0,
237 -- REFERENCES page(page_id) ON DELETE CASCADE,
238 el_to VARCHAR(1024) NOT NULL,
239 el_index VARCHAR(1024) NOT NULL
240 );
241 CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to);
242 CREATE INDEX externallinks_index ON externallinks (el_index);
243
244
245 --
246 -- Track external user accounts, if ExternalAuth is used
247 --
248 CREATE TABLE external_user (
249 -- Foreign key to user_id
250 eu_local_id BIGINT NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
251
252 -- Some opaque identifier provided by the external database
253 eu_external_id VARCHAR(255) NOT NULL
254 );
255 CREATE UNIQUE INDEX eu_external_id_idx
256 ON external_user (eu_external_id)
257 INCLUDE (eu_local_id);
258 CREATE UNIQUE INDEX eu_local_id_idx
259 ON external_user (eu_local_id)
260 INCLUDE (eu_external_id);
261
262
263
264 CREATE TABLE langlinks (
265 ll_from BIGINT NOT NULL DEFAULT 0,
266 -- REFERENCES page (page_id) ON DELETE CASCADE,
267 ll_lang VARCHAR(20),
268 ll_title VARCHAR(255)
269 );
270 CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang);
271 CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title);
272
273
274 CREATE TABLE site_stats (
275 ss_row_id BIGINT NOT NULL UNIQUE,
276 ss_total_views BIGINT DEFAULT 0,
277 ss_total_edits BIGINT DEFAULT 0,
278 ss_good_articles BIGINT DEFAULT 0,
279 ss_total_pages INTEGER DEFAULT -1,
280 ss_users INTEGER DEFAULT -1,
281 ss_active_users INTEGER DEFAULT -1,
282 ss_admins INTEGER DEFAULT -1,
283 ss_images INTEGER DEFAULT 0
284 );
285
286 CREATE TABLE hitcounter (
287 hc_id BIGINT NOT NULL
288 );
289
290 CREATE TABLE ipblocks (
291 ipb_id INTEGER NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
292 --DEFAULT nextval('ipblocks_ipb_id_val'),
293 ipb_address VARCHAR(1024),
294 ipb_user BIGINT NOT NULL DEFAULT 0,
295 -- REFERENCES user(user_id) ON DELETE SET NULL,
296 ipb_by BIGINT NOT NULL DEFAULT 0,
297 -- REFERENCES user(user_id) ON DELETE CASCADE,
298 ipb_by_text VARCHAR(255) NOT NULL DEFAULT '',
299 ipb_reason VARCHAR(1024) NOT NULL,
300 ipb_timestamp TIMESTAMP(3) NOT NULL,
301 ipb_auto SMALLINT NOT NULL DEFAULT 0,
302 ipb_anon_only SMALLINT NOT NULL DEFAULT 0,
303 ipb_create_account SMALLINT NOT NULL DEFAULT 1,
304 ipb_enable_autoblock SMALLINT NOT NULL DEFAULT 1,
305 ipb_expiry TIMESTAMP(3) NOT NULL,
306 ipb_range_start VARCHAR(1024),
307 ipb_range_end VARCHAR(1024),
308 ipb_deleted SMALLINT NOT NULL DEFAULT 0,
309 ipb_block_email SMALLINT NOT NULL DEFAULT 0,
310 ipb_allow_usertalk SMALLINT NOT NULL DEFAULT 0
311
312 );
313 CREATE INDEX ipb_address ON ipblocks (ipb_address);
314 CREATE INDEX ipb_user ON ipblocks (ipb_user);
315 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
316
317
318
319 CREATE TABLE image (
320 img_name VARCHAR(255) NOT NULL PRIMARY KEY,
321 img_size BIGINT NOT NULL,
322 img_width INTEGER NOT NULL,
323 img_height INTEGER NOT NULL,
324 img_metadata CLOB(16M) INLINE LENGTH 4096 NOT NULL DEFAULT '',
325 img_bits SMALLINT,
326 img_media_type VARCHAR(255),
327 img_major_mime VARCHAR(255) DEFAULT 'unknown',
328 img_minor_mime VARCHAR(32) DEFAULT 'unknown',
329 img_description VARCHAR(1024) NOT NULL DEFAULT '',
330 img_user BIGINT NOT NULL DEFAULT 0,
331 -- REFERENCES user(user_id) ON DELETE SET NULL,
332 img_user_text VARCHAR(255) NOT NULL DEFAULT '',
333 img_timestamp TIMESTAMP(3),
334 img_sha1 VARCHAR(255) NOT NULL DEFAULT ''
335 );
336 CREATE INDEX img_size_idx ON image (img_size);
337 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
338 CREATE INDEX img_sha1 ON image (img_sha1);
339
340 CREATE TABLE oldimage (
341 oi_name VARCHAR(255) NOT NULL DEFAULT '',
342 oi_archive_name VARCHAR(255) NOT NULL,
343 oi_size BIGINT NOT NULL,
344 oi_width INTEGER NOT NULL,
345 oi_height INTEGER NOT NULL,
346 oi_bits SMALLINT NOT NULL,
347 oi_description VARCHAR(1024),
348 oi_user BIGINT NOT NULL DEFAULT 0,
349 -- REFERENCES user(user_id) ON DELETE SET NULL,
350 oi_user_text VARCHAR(255) NOT NULL,
351 oi_timestamp TIMESTAMP(3) NOT NULL,
352 oi_metadata CLOB(16M) INLINE LENGTH 4096 NOT NULL DEFAULT '',
353 oi_media_type VARCHAR(255) ,
354 oi_major_mime VARCHAR(255) NOT NULL DEFAULT 'unknown',
355 oi_minor_mime VARCHAR(255) NOT NULL DEFAULT 'unknown',
356 oi_deleted SMALLINT NOT NULL DEFAULT 0,
357 oi_sha1 VARCHAR(255) NOT NULL DEFAULT ''
358 --FOREIGN KEY (oi_name) REFERENCES image(img_name) ON DELETE CASCADE
359 );
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 GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
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(64) DEFAULT '',
373 fa_deleted_user BIGINT 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 BIGINT 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 BIGINT 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 GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
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 BIGINT 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 BIGINT NOT NULL DEFAULT 0,
413 -- REFERENCES page(page_id) ON DELETE SET NULL,
414 rc_this_oldid BIGINT NOT NULL,
415 rc_last_oldid BIGINT 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 BIGINT 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 BIGINT 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_api CLOB(64K) INLINE LENGTH 4096 NOT NULL,
461 iw_wikiid varchar(64) NOT NULL,
462 iw_local SMALLINT NOT NULL,
463 iw_trans SMALLINT NOT NULL DEFAULT 0
464 );
465
466
467 CREATE TABLE querycache (
468 qc_type VARCHAR(255) NOT NULL,
469 qc_value BIGINT NOT NULL,
470 qc_namespace INTEGER NOT NULL,
471 qc_title VARCHAR(255) NOT NULL
472 );
473 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
474
475
476
477 CREATE TABLE querycache_info (
478 qci_type VARCHAR(255) UNIQUE NOT NULL,
479 qci_timestamp TIMESTAMP(3)
480 );
481
482
483 CREATE TABLE querycachetwo (
484 qcc_type VARCHAR(255) NOT NULL,
485 qcc_value BIGINT NOT NULL DEFAULT 0,
486 qcc_namespace INTEGER NOT NULL DEFAULT 0,
487 qcc_title VARCHAR(255) NOT NULL DEFAULT '',
488 qcc_namespacetwo INTEGER NOT NULL DEFAULT 0,
489 qcc_titletwo VARCHAR(255) NOT NULL DEFAULT ''
490 );
491 CREATE INDEX querycachetwo_type_value ON querycachetwo (qcc_type, qcc_value);
492 CREATE INDEX querycachetwo_title ON querycachetwo (qcc_type,qcc_namespace,qcc_title);
493 CREATE INDEX querycachetwo_titletwo ON querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
494
495 CREATE TABLE objectcache (
496 keyname VARCHAR(255) NOT NULL UNIQUE, -- was nullable
497 value CLOB(16M) INLINE LENGTH 4096 NOT NULL DEFAULT '',
498 exptime TIMESTAMP(3) NOT NULL
499 );
500 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
501
502
503
504 CREATE TABLE transcache (
505 tc_url VARCHAR(255) NOT NULL UNIQUE,
506 tc_contents CLOB(64K) INLINE LENGTH 4096 NOT NULL,
507 tc_time TIMESTAMP(3) NOT NULL
508 );
509
510
511 CREATE TABLE logging (
512 log_id BIGINT NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
513 --PRIMARY KEY DEFAULT nextval('log_log_id_seq'),
514 log_type VARCHAR(32) NOT NULL,
515 log_action VARCHAR(32) NOT NULL,
516 log_timestamp TIMESTAMP(3) NOT NULL,
517 log_user BIGINT NOT NULL DEFAULT 0,
518 -- REFERENCES user(user_id) ON DELETE SET NULL,
519 -- Name of the user who performed this action
520 log_user_text VARCHAR(255) NOT NULL default '',
521 log_namespace SMALLINT NOT NULL,
522 log_title VARCHAR(255) NOT NULL,
523 log_page BIGINT,
524 log_comment VARCHAR(255),
525 log_params CLOB(64K) INLINE LENGTH 4096,
526 log_deleted SMALLINT NOT NULL DEFAULT 0
527 );
528 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
529 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
530 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
531 CREATE INDEX log_user_type_time ON logging (log_user, log_type, log_timestamp);
532 CREATE INDEX log_page_id_time ON logging (log_page,log_timestamp);
533
534
535
536 CREATE TABLE trackbacks (
537 tb_id INTEGER NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
538 --PRIMARY KEY DEFAULT nextval('trackbacks_tb_id_seq'),
539 -- foreign key also in MySQL
540 tb_page INTEGER,
541 -- REFERENCES page(page_id) ON DELETE CASCADE,
542 tb_title VARCHAR(255) NOT NULL,
543 tb_url CLOB(64K) INLINE LENGTH 4096 NOT NULL,
544 tb_ex CLOB(64K) INLINE LENGTH 4096,
545 tb_name VARCHAR(255)
546 );
547 CREATE INDEX trackback_page ON trackbacks (tb_page);
548
549
550
551 CREATE TABLE job (
552 job_id BIGINT NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
553 --PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
554 job_cmd VARCHAR(255) NOT NULL,
555 job_namespace SMALLINT NOT NULL,
556 job_title VARCHAR(255) NOT NULL,
557 job_params CLOB(64K) INLINE LENGTH 4096 NOT NULL
558 );
559 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
560
561
562 --TODO
563 --CREATE FUNCTION add_interwiki (TEXT,INT,SMALLINT) RETURNS INT LANGUAGE SQL AS
564 --$mw$
565 -- INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
566 -- SELECT 1;
567 --$mw$;
568
569 -- hack implementation
570 -- should be replaced with OmniFind, Contains(), etc
571 CREATE TABLE searchindex (
572 si_page BIGINT NOT NULL,
573 si_title varchar(255) NOT NULL default '',
574 si_text clob NOT NULL
575 );
576
577 -- This table is not used unless profiling is turned on
578 CREATE TABLE profiling (
579 pf_count INTEGER NOT NULL DEFAULT 0,
580 pf_time NUMERIC(18,10) NOT NULL DEFAULT 0,
581 pf_memory NUMERIC(18,10) NOT NULL DEFAULT 0,
582 pf_name VARCHAR(255) NOT NULL,
583 pf_server VARCHAR(255)
584 );
585 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
586
587 CREATE TABLE protected_titles (
588 pt_namespace INTEGER NOT NULL,
589 pt_title VARCHAR(255) NOT NULL,
590 pt_user BIGINT NOT NULL DEFAULT 0,
591 -- REFERENCES user(user_id) ON DELETE SET NULL,
592 pt_reason VARCHAR(1024),
593 pt_timestamp TIMESTAMP(3) NOT NULL,
594 pt_expiry TIMESTAMP(3) ,
595 pt_create_perm VARCHAR(60) NOT NULL DEFAULT ''
596 );
597 CREATE UNIQUE INDEX protected_titles_unique ON protected_titles(pt_namespace, pt_title);
598
599
600
601 CREATE TABLE updatelog (
602 ul_key VARCHAR(255) NOT NULL PRIMARY KEY
603 );
604
605
606 CREATE TABLE category (
607 cat_id INTEGER NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
608 --PRIMARY KEY DEFAULT nextval('category_id_seq'),
609 cat_title VARCHAR(255) NOT NULL,
610 cat_pages INTEGER NOT NULL DEFAULT 0,
611 cat_subcats INTEGER NOT NULL DEFAULT 0,
612 cat_files INTEGER NOT NULL DEFAULT 0,
613 cat_hidden SMALLINT NOT NULL DEFAULT 0
614 );
615 CREATE UNIQUE INDEX category_title ON category(cat_title);
616 CREATE INDEX category_pages ON category(cat_pages);
617
618 -- added for 1.15
619
620 -- A table to track tags for revisions, logs and recent changes.
621 CREATE TABLE change_tag (
622 ct_rc_id INTEGER,
623 ct_log_id INTEGER,
624 ct_rev_id INTEGER,
625 ct_tag varchar(255) NOT NULL,
626 ct_params CLOB(64K) INLINE LENGTH 4096
627 );
628 CREATE UNIQUE INDEX change_tag_rc_tag ON change_tag (ct_rc_id,ct_tag);
629 CREATE UNIQUE INDEX change_tag_log_tag ON change_tag (ct_log_id,ct_tag);
630 CREATE UNIQUE INDEX change_tag_rev_tag ON change_tag (ct_rev_id,ct_tag);
631 -- Covering index, so we can pull all the info only out of the index.
632 CREATE INDEX change_tag_tag_id ON change_tag (ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
633
634
635 -- Rollup table to pull a LIST of tags simply
636 CREATE TABLE tag_summary (
637 ts_rc_id INTEGER,
638 ts_log_id INTEGER,
639 ts_rev_id INTEGER,
640 ts_tags CLOB(64K) INLINE LENGTH 4096 NOT NULL
641 );
642 CREATE UNIQUE INDEX tag_summary_rc_id ON tag_summary (ts_rc_id);
643 CREATE UNIQUE INDEX tag_summary_log_id ON tag_summary (ts_log_id);
644 CREATE UNIQUE INDEX tag_summary_rev_id ON tag_summary (ts_rev_id);
645
646
647 CREATE TABLE valid_tag (
648 vt_tag varchar(255) NOT NULL PRIMARY KEY
649 );
650
651 --
652 -- User preferences and perhaps other fun stuff. :)
653 -- Replaces the old user.user_options blob, with a couple nice properties:
654 --
655 -- 1) We only store non-default settings, so changes to the defaults
656 -- are now reflected for everybody, not just new accounts.
657 -- 2) We can more easily do bulk lookups, statistics, or modifications of
658 -- saved options since it's a sane table structure.
659 --
660 CREATE TABLE user_properties (
661 -- Foreign key to user.user_id
662 up_user BIGINT NOT NULL,
663
664 -- Name of the option being saved. This is indexed for bulk lookup.
665 up_property VARCHAR(32) FOR BIT DATA NOT NULL,
666
667 -- Property value as a string.
668 up_value CLOB(64K) INLINE LENGTH 4096
669 );
670 CREATE UNIQUE INDEX user_properties_user_property ON user_properties (up_user,up_property);
671 CREATE INDEX user_properties_property ON user_properties (up_property);
672
673 CREATE TABLE log_search (
674 -- The type of ID (rev ID, log ID, rev TIMESTAMP(3), username)
675 ls_field VARCHAR(32) FOR BIT DATA NOT NULL,
676 -- The value of the ID
677 ls_value varchar(255) NOT NULL,
678 -- Key to log_id
679 ls_log_id BIGINT NOT NULL default 0
680 );
681 CREATE UNIQUE INDEX ls_field_val ON log_search (ls_field,ls_value,ls_log_id);
682 CREATE INDEX ls_log_id ON log_search (ls_log_id);
683
684 -- Table for storing localisation data
685 CREATE TABLE l10n_cache (
686 -- Language code
687 lc_lang VARCHAR(32) NOT NULL,
688 -- Cache key
689 lc_key VARCHAR(255) NOT NULL,
690 -- Value
691 lc_value CLOB(16M) INLINE LENGTH 4096 NOT NULL
692 );
693 CREATE INDEX lc_lang_key ON l10n_cache (lc_lang, lc_key);
694
695
696 CREATE TABLE "MSG_RESOURCE_LINKS"
697 (
698 "MRL_RESOURCE" VARCHAR(255) FOR BIT DATA NOT NULL ,
699 "MRL_MESSAGE" VARCHAR(255) FOR BIT DATA NOT NULL
700 )
701 ;
702
703 CREATE UNIQUE INDEX "UQ61_MSG_RESOURCE_LINKS" ON "MSG_RESOURCE_LINKS"
704 (
705 "MRL_MESSAGE",
706 "MRL_RESOURCE"
707 )
708 ALLOW REVERSE SCANS
709 ;
710
711 CREATE TABLE "MSG_RESOURCE"
712 (
713 "MR_RESOURCE" VARCHAR(255) FOR BIT DATA NOT NULL ,
714 "MR_LANG" VARCHAR(32) FOR BIT DATA NOT NULL ,
715 "MR_BLOB" BLOB NOT NULL ,
716 "MR_TIMESTAMP" TIMESTAMP(3) NOT NULL
717 )
718 ;
719
720 CREATE UNIQUE INDEX "UQ81_MSG_RESOURCE" ON "MSG_RESOURCE"
721 (
722 "MR_RESOURCE"
723 ,"MR_LANG"
724 )
725 ALLOW REVERSE SCANS
726 ;
727
728 CREATE TABLE "MODULE_DEPS" (
729 "MD_MODULE" VARCHAR(255) FOR BIT DATA NOT NULL ,
730 "MD_SKIN" VARCHAR(32) FOR BIT DATA NOT NULL ,
731 "MD_DEPS" CLOB(16M) INLINE LENGTH 4096 NOT NULL
732 )
733 ;
734
735 CREATE UNIQUE INDEX "UQ96_MODULE_DEPS" ON "MODULE_DEPS"
736 (
737 "MD_MODULE"
738 ,"MD_SKIN"
739 )
740 ALLOW REVERSE SCANS
741 ;
742
743 CREATE TABLE "IWLINKS"
744 (
745 "IWL_FROM" INT NOT NULL ,
746 "IWL_PREFIX" VARCHAR(20) FOR BIT DATA NOT NULL ,
747 "IWL_TITLE" VARCHAR(255) FOR BIT DATA NOT NULL
748 )
749 ;