Fix ranges formatting issue when testing for (g,z) in IPv6 address
[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_timestamp TIMESTAMP(3) NOT NULL
225 );
226 CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to);
227 CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey, cl_from);
228
229
230
231 CREATE TABLE externallinks (
232 el_from BIGINT NOT NULL DEFAULT 0,
233 -- REFERENCES page(page_id) ON DELETE CASCADE,
234 el_to VARCHAR(1024) NOT NULL,
235 el_index VARCHAR(1024) NOT NULL
236 );
237 CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to);
238 CREATE INDEX externallinks_index ON externallinks (el_index);
239
240
241 --
242 -- Track external user accounts, if ExternalAuth is used
243 --
244 CREATE TABLE external_user (
245 -- Foreign key to user_id
246 eu_local_id BIGINT NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
247
248 -- Some opaque identifier provided by the external database
249 eu_external_id VARCHAR(255) NOT NULL
250 );
251 CREATE UNIQUE INDEX eu_external_id_idx
252 ON external_user (eu_external_id)
253 INCLUDE (eu_local_id);
254 CREATE UNIQUE INDEX eu_local_id_idx
255 ON external_user (eu_local_id)
256 INCLUDE (eu_external_id);
257
258
259
260 CREATE TABLE langlinks (
261 ll_from BIGINT NOT NULL DEFAULT 0,
262 -- REFERENCES page (page_id) ON DELETE CASCADE,
263 ll_lang VARCHAR(20),
264 ll_title VARCHAR(255)
265 );
266 CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang);
267 CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title);
268
269
270 CREATE TABLE site_stats (
271 ss_row_id BIGINT NOT NULL UNIQUE,
272 ss_total_views BIGINT DEFAULT 0,
273 ss_total_edits BIGINT DEFAULT 0,
274 ss_good_articles BIGINT DEFAULT 0,
275 ss_total_pages INTEGER DEFAULT -1,
276 ss_users INTEGER DEFAULT -1,
277 ss_active_users INTEGER DEFAULT -1,
278 ss_admins INTEGER DEFAULT -1,
279 ss_images INTEGER DEFAULT 0
280 );
281
282 CREATE TABLE hitcounter (
283 hc_id BIGINT NOT NULL
284 );
285
286 CREATE TABLE ipblocks (
287 ipb_id INTEGER NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
288 --DEFAULT nextval('ipblocks_ipb_id_val'),
289 ipb_address VARCHAR(1024),
290 ipb_user BIGINT NOT NULL DEFAULT 0,
291 -- REFERENCES user(user_id) ON DELETE SET NULL,
292 ipb_by BIGINT NOT NULL DEFAULT 0,
293 -- REFERENCES user(user_id) ON DELETE CASCADE,
294 ipb_by_text VARCHAR(255) NOT NULL DEFAULT '',
295 ipb_reason VARCHAR(1024) NOT NULL,
296 ipb_timestamp TIMESTAMP(3) NOT NULL,
297 ipb_auto SMALLINT NOT NULL DEFAULT 0,
298 ipb_anon_only SMALLINT NOT NULL DEFAULT 0,
299 ipb_create_account SMALLINT NOT NULL DEFAULT 1,
300 ipb_enable_autoblock SMALLINT NOT NULL DEFAULT 1,
301 ipb_expiry TIMESTAMP(3) NOT NULL,
302 ipb_range_start VARCHAR(1024),
303 ipb_range_end VARCHAR(1024),
304 ipb_deleted SMALLINT NOT NULL DEFAULT 0,
305 ipb_block_email SMALLINT NOT NULL DEFAULT 0,
306 ipb_allow_usertalk SMALLINT NOT NULL DEFAULT 0
307
308 );
309 CREATE INDEX ipb_address ON ipblocks (ipb_address);
310 CREATE INDEX ipb_user ON ipblocks (ipb_user);
311 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end);
312
313
314
315 CREATE TABLE image (
316 img_name VARCHAR(255) NOT NULL PRIMARY KEY,
317 img_size BIGINT NOT NULL,
318 img_width INTEGER NOT NULL,
319 img_height INTEGER NOT NULL,
320 img_metadata CLOB(16M) INLINE LENGTH 4096 NOT NULL DEFAULT '',
321 img_bits SMALLINT,
322 img_media_type VARCHAR(255),
323 img_major_mime VARCHAR(255) DEFAULT 'unknown',
324 img_minor_mime VARCHAR(32) DEFAULT 'unknown',
325 img_description VARCHAR(1024) NOT NULL DEFAULT '',
326 img_user BIGINT NOT NULL DEFAULT 0,
327 -- REFERENCES user(user_id) ON DELETE SET NULL,
328 img_user_text VARCHAR(255) NOT NULL DEFAULT '',
329 img_timestamp TIMESTAMP(3),
330 img_sha1 VARCHAR(255) NOT NULL DEFAULT ''
331 );
332 CREATE INDEX img_size_idx ON image (img_size);
333 CREATE INDEX img_timestamp_idx ON image (img_timestamp);
334 CREATE INDEX img_sha1 ON image (img_sha1);
335
336 CREATE TABLE oldimage (
337 oi_name VARCHAR(255) NOT NULL DEFAULT '',
338 oi_archive_name VARCHAR(255) NOT NULL,
339 oi_size BIGINT NOT NULL,
340 oi_width INTEGER NOT NULL,
341 oi_height INTEGER NOT NULL,
342 oi_bits SMALLINT NOT NULL,
343 oi_description VARCHAR(1024),
344 oi_user BIGINT NOT NULL DEFAULT 0,
345 -- REFERENCES user(user_id) ON DELETE SET NULL,
346 oi_user_text VARCHAR(255) NOT NULL,
347 oi_timestamp TIMESTAMP(3) NOT NULL,
348 oi_metadata CLOB(16M) INLINE LENGTH 4096 NOT NULL DEFAULT '',
349 oi_media_type VARCHAR(255) ,
350 oi_major_mime VARCHAR(255) NOT NULL DEFAULT 'unknown',
351 oi_minor_mime VARCHAR(255) NOT NULL DEFAULT 'unknown',
352 oi_deleted SMALLINT NOT NULL DEFAULT 0,
353 oi_sha1 VARCHAR(255) NOT NULL DEFAULT ''
354 --FOREIGN KEY (oi_name) REFERENCES image(img_name) ON DELETE CASCADE
355 );
356 CREATE INDEX oi_name_timestamp ON oldimage (oi_name,oi_timestamp);
357 CREATE INDEX oi_name_archive_name ON oldimage (oi_name,oi_archive_name);
358 CREATE INDEX oi_sha1 ON oldimage (oi_sha1);
359
360
361
362 CREATE TABLE filearchive (
363 fa_id INTEGER NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
364 --PRIMARY KEY DEFAULT nextval('filearchive_fa_id_seq'),
365 fa_name VARCHAR(255) NOT NULL,
366 fa_archive_name VARCHAR(255),
367 fa_storage_group VARCHAR(255),
368 fa_storage_key VARCHAR(64) DEFAULT '',
369 fa_deleted_user BIGINT NOT NULL DEFAULT 0,
370 -- REFERENCES user(user_id) ON DELETE SET NULL,
371 fa_deleted_timestamp TIMESTAMP(3) NOT NULL,
372 fa_deleted_reason VARCHAR(255),
373 fa_size BIGINT NOT NULL,
374 fa_width INTEGER NOT NULL,
375 fa_height INTEGER NOT NULL,
376 fa_metadata CLOB(16M) INLINE LENGTH 4096 NOT NULL DEFAULT '',
377 fa_bits SMALLINT,
378 fa_media_type VARCHAR(255),
379 fa_major_mime VARCHAR(255) DEFAULT 'unknown',
380 fa_minor_mime VARCHAR(255) DEFAULT 'unknown',
381 fa_description VARCHAR(1024) NOT NULL,
382 fa_user BIGINT NOT NULL DEFAULT 0,
383 -- REFERENCES user(user_id) ON DELETE SET NULL,
384 fa_user_text VARCHAR(255) NOT NULL,
385 fa_timestamp TIMESTAMP(3),
386 fa_deleted SMALLINT NOT NULL DEFAULT 0
387 );
388 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp);
389 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key);
390 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp);
391 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user);
392
393
394 CREATE TABLE recentchanges (
395 rc_id INTEGER NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
396 --PRIMARY KEY DEFAULT nextval('rc_rc_id_seq'),
397 rc_timestamp TIMESTAMP(3) NOT NULL,
398 rc_cur_time TIMESTAMP(3) NOT NULL,
399 rc_user BIGINT NOT NULL DEFAULT 0,
400 -- REFERENCES user(user_id) ON DELETE SET NULL,
401 rc_user_text VARCHAR(255) NOT NULL,
402 rc_namespace SMALLINT NOT NULL,
403 rc_title VARCHAR(255) NOT NULL,
404 rc_comment VARCHAR(255),
405 rc_minor SMALLINT NOT NULL DEFAULT 0,
406 rc_bot SMALLINT NOT NULL DEFAULT 0,
407 rc_new SMALLINT NOT NULL DEFAULT 0,
408 rc_cur_id BIGINT NOT NULL DEFAULT 0,
409 -- REFERENCES page(page_id) ON DELETE SET NULL,
410 rc_this_oldid BIGINT NOT NULL,
411 rc_last_oldid BIGINT NOT NULL,
412 rc_type SMALLINT NOT NULL DEFAULT 0,
413 rc_moved_to_ns SMALLINT,
414 rc_moved_to_title VARCHAR(255),
415 rc_patrolled SMALLINT NOT NULL DEFAULT 0,
416 rc_ip VARCHAR(40), -- was CIDR type
417 rc_old_len INTEGER,
418 rc_new_len INTEGER,
419 rc_deleted SMALLINT NOT NULL DEFAULT 0,
420 rc_logid BIGINT NOT NULL DEFAULT 0,
421 rc_log_type VARCHAR(255),
422 rc_log_action VARCHAR(255),
423 rc_params CLOB(64K) INLINE LENGTH 4096
424
425 );
426 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp);
427 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title);
428 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id);
429 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp);
430 CREATE INDEX rc_ip ON recentchanges (rc_ip);
431
432
433
434 CREATE TABLE watchlist (
435 wl_user BIGINT NOT NULL DEFAULT 0,
436 -- REFERENCES user(user_id) ON DELETE CASCADE,
437 wl_namespace SMALLINT NOT NULL DEFAULT 0,
438 wl_title VARCHAR(255) NOT NULL,
439 wl_notificationtimestamp TIMESTAMP(3)
440 );
441 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user);
442
443
444 CREATE TABLE math (
445 math_inputhash VARCHAR(16) FOR BIT DATA NOT NULL UNIQUE,
446 math_outputhash VARCHAR(16) FOR BIT DATA NOT NULL,
447 math_html_conservativeness SMALLINT NOT NULL,
448 math_html CLOB(64K) INLINE LENGTH 4096,
449 math_mathml CLOB(64K) INLINE LENGTH 4096
450 );
451
452
453 CREATE TABLE interwiki (
454 iw_prefix VARCHAR(32) NOT NULL UNIQUE,
455 iw_url CLOB(64K) INLINE LENGTH 4096 NOT NULL,
456 iw_local SMALLINT NOT NULL,
457 iw_trans SMALLINT NOT NULL DEFAULT 0
458 );
459
460
461 CREATE TABLE querycache (
462 qc_type VARCHAR(255) NOT NULL,
463 qc_value BIGINT NOT NULL,
464 qc_namespace INTEGER NOT NULL,
465 qc_title VARCHAR(255) NOT NULL
466 );
467 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value);
468
469
470
471 CREATE TABLE querycache_info (
472 qci_type VARCHAR(255) UNIQUE NOT NULL,
473 qci_timestamp TIMESTAMP(3)
474 );
475
476
477 CREATE TABLE querycachetwo (
478 qcc_type VARCHAR(255) NOT NULL,
479 qcc_value BIGINT NOT NULL DEFAULT 0,
480 qcc_namespace INTEGER NOT NULL DEFAULT 0,
481 qcc_title VARCHAR(255) NOT NULL DEFAULT '',
482 qcc_namespacetwo INTEGER NOT NULL DEFAULT 0,
483 qcc_titletwo VARCHAR(255) NOT NULL DEFAULT ''
484 );
485 CREATE INDEX querycachetwo_type_value ON querycachetwo (qcc_type, qcc_value);
486 CREATE INDEX querycachetwo_title ON querycachetwo (qcc_type,qcc_namespace,qcc_title);
487 CREATE INDEX querycachetwo_titletwo ON querycachetwo (qcc_type,qcc_namespacetwo,qcc_titletwo);
488
489 CREATE TABLE objectcache (
490 keyname VARCHAR(255) NOT NULL UNIQUE, -- was nullable
491 value CLOB(16M) INLINE LENGTH 4096 NOT NULL DEFAULT '',
492 exptime TIMESTAMP(3) NOT NULL
493 );
494 CREATE INDEX objectcacache_exptime ON objectcache (exptime);
495
496
497
498 CREATE TABLE transcache (
499 tc_url VARCHAR(255) NOT NULL UNIQUE,
500 tc_contents CLOB(64K) INLINE LENGTH 4096 NOT NULL,
501 tc_time TIMESTAMP(3) NOT NULL
502 );
503
504
505 CREATE TABLE logging (
506 log_id BIGINT NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
507 --PRIMARY KEY DEFAULT nextval('log_log_id_seq'),
508 log_type VARCHAR(32) NOT NULL,
509 log_action VARCHAR(32) NOT NULL,
510 log_timestamp TIMESTAMP(3) NOT NULL,
511 log_user BIGINT NOT NULL DEFAULT 0,
512 -- REFERENCES user(user_id) ON DELETE SET NULL,
513 -- Name of the user who performed this action
514 log_user_text VARCHAR(255) NOT NULL default '',
515 log_namespace SMALLINT NOT NULL,
516 log_title VARCHAR(255) NOT NULL,
517 log_page BIGINT,
518 log_comment VARCHAR(255),
519 log_params CLOB(64K) INLINE LENGTH 4096,
520 log_deleted SMALLINT NOT NULL DEFAULT 0
521 );
522 CREATE INDEX logging_type_name ON logging (log_type, log_timestamp);
523 CREATE INDEX logging_user_time ON logging (log_timestamp, log_user);
524 CREATE INDEX logging_page_time ON logging (log_namespace, log_title, log_timestamp);
525 CREATE INDEX log_user_type_time ON logging (log_user, log_type, log_timestamp);
526 CREATE INDEX log_page_id_time ON logging (log_page,log_timestamp);
527
528
529
530 CREATE TABLE trackbacks (
531 tb_id INTEGER NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
532 --PRIMARY KEY DEFAULT nextval('trackbacks_tb_id_seq'),
533 -- foreign key also in MySQL
534 tb_page INTEGER,
535 -- REFERENCES page(page_id) ON DELETE CASCADE,
536 tb_title VARCHAR(255) NOT NULL,
537 tb_url CLOB(64K) INLINE LENGTH 4096 NOT NULL,
538 tb_ex CLOB(64K) INLINE LENGTH 4096,
539 tb_name VARCHAR(255)
540 );
541 CREATE INDEX trackback_page ON trackbacks (tb_page);
542
543
544
545 CREATE TABLE job (
546 job_id BIGINT NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
547 --PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
548 job_cmd VARCHAR(255) NOT NULL,
549 job_namespace SMALLINT NOT NULL,
550 job_title VARCHAR(255) NOT NULL,
551 job_params CLOB(64K) INLINE LENGTH 4096 NOT NULL
552 );
553 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
554
555
556 --TODO
557 --CREATE FUNCTION add_interwiki (TEXT,INT,SMALLINT) RETURNS INT LANGUAGE SQL AS
558 --$mw$
559 -- INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
560 -- SELECT 1;
561 --$mw$;
562
563 -- hack implementation
564 -- should be replaced with OmniFind, Contains(), etc
565 CREATE TABLE searchindex (
566 si_page BIGINT NOT NULL,
567 si_title varchar(255) NOT NULL default '',
568 si_text clob NOT NULL
569 );
570
571 -- This table is not used unless profiling is turned on
572 CREATE TABLE profiling (
573 pf_count INTEGER NOT NULL DEFAULT 0,
574 pf_time NUMERIC(18,10) NOT NULL DEFAULT 0,
575 pf_memory NUMERIC(18,10) NOT NULL DEFAULT 0,
576 pf_name VARCHAR(255) NOT NULL,
577 pf_server VARCHAR(255)
578 );
579 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
580
581 CREATE TABLE protected_titles (
582 pt_namespace INTEGER NOT NULL,
583 pt_title VARCHAR(255) NOT NULL,
584 pt_user BIGINT NOT NULL DEFAULT 0,
585 -- REFERENCES user(user_id) ON DELETE SET NULL,
586 pt_reason VARCHAR(1024),
587 pt_timestamp TIMESTAMP(3) NOT NULL,
588 pt_expiry TIMESTAMP(3) ,
589 pt_create_perm VARCHAR(60) NOT NULL DEFAULT ''
590 );
591 CREATE UNIQUE INDEX protected_titles_unique ON protected_titles(pt_namespace, pt_title);
592
593
594
595 CREATE TABLE updatelog (
596 ul_key VARCHAR(255) NOT NULL PRIMARY KEY
597 );
598
599
600 CREATE TABLE category (
601 cat_id INTEGER NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
602 --PRIMARY KEY DEFAULT nextval('category_id_seq'),
603 cat_title VARCHAR(255) NOT NULL,
604 cat_pages INTEGER NOT NULL DEFAULT 0,
605 cat_subcats INTEGER NOT NULL DEFAULT 0,
606 cat_files INTEGER NOT NULL DEFAULT 0,
607 cat_hidden SMALLINT NOT NULL DEFAULT 0
608 );
609 CREATE UNIQUE INDEX category_title ON category(cat_title);
610 CREATE INDEX category_pages ON category(cat_pages);
611
612 -- added for 1.15
613
614 -- A table to track tags for revisions, logs and recent changes.
615 CREATE TABLE change_tag (
616 ct_rc_id INTEGER,
617 ct_log_id INTEGER,
618 ct_rev_id INTEGER,
619 ct_tag varchar(255) NOT NULL,
620 ct_params CLOB(64K) INLINE LENGTH 4096
621 );
622 CREATE UNIQUE INDEX change_tag_rc_tag ON change_tag (ct_rc_id,ct_tag);
623 CREATE UNIQUE INDEX change_tag_log_tag ON change_tag (ct_log_id,ct_tag);
624 CREATE UNIQUE INDEX change_tag_rev_tag ON change_tag (ct_rev_id,ct_tag);
625 -- Covering index, so we can pull all the info only out of the index.
626 CREATE INDEX change_tag_tag_id ON change_tag (ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
627
628
629 -- Rollup table to pull a LIST of tags simply
630 CREATE TABLE tag_summary (
631 ts_rc_id INTEGER,
632 ts_log_id INTEGER,
633 ts_rev_id INTEGER,
634 ts_tags CLOB(64K) INLINE LENGTH 4096 NOT NULL
635 );
636 CREATE UNIQUE INDEX tag_summary_rc_id ON tag_summary (ts_rc_id);
637 CREATE UNIQUE INDEX tag_summary_log_id ON tag_summary (ts_log_id);
638 CREATE UNIQUE INDEX tag_summary_rev_id ON tag_summary (ts_rev_id);
639
640
641 CREATE TABLE valid_tag (
642 vt_tag varchar(255) NOT NULL PRIMARY KEY
643 );
644
645 --
646 -- User preferences and perhaps other fun stuff. :)
647 -- Replaces the old user.user_options blob, with a couple nice properties:
648 --
649 -- 1) We only store non-default settings, so changes to the defaults
650 -- are now reflected for everybody, not just new accounts.
651 -- 2) We can more easily do bulk lookups, statistics, or modifications of
652 -- saved options since it's a sane table structure.
653 --
654 CREATE TABLE user_properties (
655 -- Foreign key to user.user_id
656 up_user BIGINT NOT NULL,
657
658 -- Name of the option being saved. This is indexed for bulk lookup.
659 up_property VARCHAR(32) FOR BIT DATA NOT NULL,
660
661 -- Property value as a string.
662 up_value CLOB(64K) INLINE LENGTH 4096
663 );
664 CREATE UNIQUE INDEX user_properties_user_property ON user_properties (up_user,up_property);
665 CREATE INDEX user_properties_property ON user_properties (up_property);
666
667 CREATE TABLE log_search (
668 -- The type of ID (rev ID, log ID, rev TIMESTAMP(3), username)
669 ls_field VARCHAR(32) FOR BIT DATA NOT NULL,
670 -- The value of the ID
671 ls_value varchar(255) NOT NULL,
672 -- Key to log_id
673 ls_log_id BIGINT NOT NULL default 0
674 );
675 CREATE UNIQUE INDEX ls_field_val ON log_search (ls_field,ls_value,ls_log_id);
676 CREATE INDEX ls_log_id ON log_search (ls_log_id);
677
678 -- Table for storing localisation data
679 CREATE TABLE l10n_cache (
680 -- Language code
681 lc_lang VARCHAR(32) NOT NULL,
682 -- Cache key
683 lc_key VARCHAR(255) NOT NULL,
684 -- Value
685 lc_value CLOB(16M) INLINE LENGTH 4096 NOT NULL
686 );
687 CREATE INDEX lc_lang_key ON l10n_cache (lc_lang, lc_key);
688