DB2: Implemented prepared statements for INSERT and UPDATE to allow more than 32k...
[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 UNIQUE INDEX user_groups_unique ON user_groups (ug_user, ug_group);
52 --leonsp:
53 CREATE UNIQUE INDEX user_groups_include_idx
54 ON user_groups(ug_user)
55 INCLUDE (ug_group);
56
57
58 CREATE TABLE user_newtalk (
59 -- registered users key
60 user_id BIGINT NOT NULL DEFAULT 0,
61 -- REFERENCES user(user_id) ON DELETE CASCADE,
62 -- anonymous users key
63 user_ip VARCHAR(40),
64 user_last_timestamp TIMESTAMP(3)
65 );
66 CREATE INDEX user_newtalk_id_idx ON user_newtalk (user_id);
67 CREATE INDEX user_newtalk_ip_idx ON user_newtalk (user_ip);
68 --leonsp:
69 CREATE UNIQUE INDEX user_newtalk_include_idx
70 ON user_newtalk(user_id, user_ip)
71 INCLUDE (user_last_timestamp);
72
73
74 CREATE TABLE page (
75 page_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
76 page_namespace SMALLINT NOT NULL,
77 page_title VARCHAR(255) NOT NULL,
78 page_restrictions VARCHAR(1024),
79 page_counter BIGINT NOT NULL DEFAULT 0,
80 page_is_redirect SMALLINT NOT NULL DEFAULT 0,
81 page_is_new SMALLINT NOT NULL DEFAULT 0,
82 page_random NUMERIC(15,14) NOT NULL,
83 page_touched TIMESTAMP(3),
84 page_latest BIGINT NOT NULL, -- FK?
85 page_len BIGINT NOT NULL
86 );
87 CREATE UNIQUE INDEX page_unique_name ON page (page_namespace, page_title);
88 CREATE INDEX page_random_idx ON page (page_random);
89 CREATE INDEX page_len_idx ON page (page_len);
90 --leonsp:
91 CREATE UNIQUE INDEX page_id_include
92 ON page (page_id)
93 INCLUDE (page_namespace, page_title, page_restrictions, page_counter, page_is_redirect, page_is_new, page_random, page_touched, page_latest, page_len);
94 CREATE UNIQUE INDEX page_name_include
95 ON page (page_namespace, page_title)
96 INCLUDE (page_id, page_restrictions, page_counter, page_is_redirect, page_is_new, page_random, page_touched, page_latest, page_len);
97
98
99 CREATE TABLE revision (
100 rev_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
101 rev_page BIGINT NOT NULL DEFAULT 0,
102 -- REFERENCES page (page_id) ON DELETE CASCADE,
103 rev_text_id BIGINT, -- FK
104 rev_comment VARCHAR(1024),
105 rev_user BIGINT NOT NULL DEFAULT 0,
106 -- REFERENCES user(user_id) ON DELETE RESTRICT,
107 rev_user_text VARCHAR(255) NOT NULL,
108 rev_timestamp TIMESTAMP(3) NOT NULL,
109 rev_minor_edit SMALLINT NOT NULL DEFAULT 0,
110 rev_deleted SMALLINT NOT NULL DEFAULT 0,
111 rev_len BIGINT,
112 rev_parent_id BIGINT DEFAULT NULL
113 );
114 CREATE UNIQUE INDEX revision_unique ON revision (rev_page, rev_id);
115 CREATE INDEX rev_text_id_idx ON revision (rev_text_id);
116 CREATE INDEX rev_timestamp_idx ON revision (rev_timestamp);
117 CREATE INDEX rev_user_idx ON revision (rev_user);
118 CREATE INDEX rev_user_text_idx ON revision (rev_user_text);
119
120
121
122 CREATE TABLE text ( -- replaces reserved word 'text'
123 old_id INTEGER PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
124 old_text CLOB(16M) INLINE LENGTH 4096,
125 old_flags VARCHAR(1024)
126 );
127
128
129 CREATE TABLE page_restrictions (
130 --pr_id INTEGER NOT NULL UNIQUE, --DEFAULT nextval('pr_id_val'),
131 --pr_id INTEGER PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
132 pr_id BIGINT PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
133 pr_page INTEGER NOT NULL DEFAULT 0,
134 --(used to be nullable)
135 -- REFERENCES page (page_id) ON DELETE CASCADE,
136 pr_type VARCHAR(60) NOT NULL,
137 pr_level VARCHAR(60) NOT NULL,
138 pr_cascade SMALLINT NOT NULL,
139 pr_user INTEGER,
140 pr_expiry TIMESTAMP(3)
141 --PRIMARY KEY (pr_page, pr_type)
142 );
143 --ALTER TABLE page_restrictions ADD CONSTRAINT page_restrictions_pk PRIMARY KEY (pr_page,pr_type);
144 CREATE UNIQUE INDEX pr_pagetype ON page_restrictions (pr_page,pr_type);
145 CREATE INDEX pr_typelevel ON page_restrictions (pr_type,pr_level);
146 CREATE INDEX pr_level ON page_restrictions (pr_level);
147 CREATE INDEX pr_cascade ON page_restrictions (pr_cascade);
148
149 CREATE TABLE page_props (
150 pp_page INTEGER NOT NULL DEFAULT 0,
151 -- REFERENCES page (page_id) ON DELETE CASCADE,
152 pp_propname VARCHAR(255) NOT NULL,
153 pp_value CLOB(64K) INLINE LENGTH 4096 NOT NULL,
154 PRIMARY KEY (pp_page,pp_propname)
155 );
156 --ALTER TABLE page_props ADD CONSTRAINT page_props_pk PRIMARY KEY (pp_page,pp_propname);
157 CREATE INDEX page_props_propname ON page_props (pp_propname);
158
159
160
161 CREATE TABLE archive (
162 ar_namespace SMALLINT NOT NULL,
163 ar_title VARCHAR(255) NOT NULL,
164 ar_text CLOB(16M) INLINE LENGTH 4096,
165 ar_comment VARCHAR(1024),
166 ar_user BIGINT NOT NULL,
167 -- no foreign keys in MySQL
168 -- REFERENCES user(user_id) ON DELETE SET NULL,
169 ar_user_text VARCHAR(255) NOT NULL,
170 ar_timestamp TIMESTAMP(3) NOT NULL,
171 ar_minor_edit SMALLINT NOT NULL DEFAULT 0,
172 ar_flags VARCHAR(1024),
173 ar_rev_id INTEGER,
174 ar_text_id INTEGER,
175 ar_deleted SMALLINT NOT NULL DEFAULT 0,
176 ar_len INTEGER,
177 ar_page_id INTEGER,
178 ar_parent_id INTEGER
179 );
180 CREATE INDEX archive_name_title_timestamp ON archive (ar_namespace,ar_title,ar_timestamp);
181 CREATE INDEX archive_user_text ON archive (ar_user_text);
182
183
184
185 CREATE TABLE redirect (
186 rd_from BIGINT NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
187 --REFERENCES page(page_id) ON DELETE CASCADE,
188 rd_namespace SMALLINT NOT NULL DEFAULT 0,
189 rd_title VARCHAR(255) NOT NULL DEFAULT '',
190 rd_interwiki varchar(32),
191 rd_fragment VARCHAR(255)
192 );
193 CREATE INDEX redirect_ns_title ON redirect (rd_namespace,rd_title,rd_from);
194
195
196 CREATE TABLE pagelinks (
197 pl_from BIGINT NOT NULL DEFAULT 0,
198 -- REFERENCES page(page_id) ON DELETE CASCADE,
199 pl_namespace SMALLINT NOT NULL,
200 pl_title VARCHAR(255) NOT NULL
201 );
202 CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_from,pl_namespace,pl_title);
203
204 CREATE TABLE templatelinks (
205 tl_from BIGINT NOT NULL DEFAULT 0,
206 -- REFERENCES page(page_id) ON DELETE CASCADE,
207 tl_namespace SMALLINT NOT NULL,
208 tl_title VARCHAR(255) NOT NULL
209 );
210 CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from);
211 CREATE UNIQUE INDEX tl_from_idx ON templatelinks (tl_from,tl_namespace,tl_title);
212
213 CREATE TABLE imagelinks (
214 il_from BIGINT NOT NULL DEFAULT 0,
215 -- REFERENCES page(page_id) ON DELETE CASCADE,
216 il_to VARCHAR(255) NOT NULL
217 );
218 CREATE UNIQUE INDEX il_from_idx ON imagelinks (il_to,il_from);
219 CREATE UNIQUE INDEX il_to_idx ON imagelinks (il_from,il_to);
220
221 CREATE TABLE categorylinks (
222 cl_from BIGINT NOT NULL DEFAULT 0,
223 -- REFERENCES page(page_id) ON DELETE CASCADE,
224 cl_to VARCHAR(255) NOT NULL,
225 -- cl_sortkey has to be at least 86 wide
226 -- in order to be compatible with the old MySQL schema from MW 1.10
227 cl_sortkey VARCHAR(86),
228 cl_timestamp TIMESTAMP(3) 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_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 BIGINT NOT NULL,
468 qc_namespace INTEGER 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 BIGINT 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 CLOB(64K) INLINE LENGTH 4096 NOT NULL,
505 tc_time TIMESTAMP(3) NOT NULL
506 );
507
508
509 CREATE TABLE logging (
510 log_id BIGINT NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
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 BIGINT 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 BIGINT,
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 GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
536 --PRIMARY KEY DEFAULT nextval('trackbacks_tb_id_seq'),
537 -- foreign key also in MySQL
538 tb_page INTEGER,
539 -- REFERENCES page(page_id) ON DELETE CASCADE,
540 tb_title VARCHAR(255) NOT NULL,
541 tb_url CLOB(64K) INLINE LENGTH 4096 NOT NULL,
542 tb_ex CLOB(64K) INLINE LENGTH 4096,
543 tb_name VARCHAR(255)
544 );
545 CREATE INDEX trackback_page ON trackbacks (tb_page);
546
547
548
549 CREATE TABLE job (
550 job_id BIGINT NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
551 --PRIMARY KEY DEFAULT nextval('job_job_id_seq'),
552 job_cmd VARCHAR(255) NOT NULL,
553 job_namespace SMALLINT NOT NULL,
554 job_title VARCHAR(255) NOT NULL,
555 job_params CLOB(64K) INLINE LENGTH 4096 NOT NULL
556 );
557 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title);
558
559
560 --TODO
561 --CREATE FUNCTION add_interwiki (TEXT,INT,SMALLINT) RETURNS INT LANGUAGE SQL AS
562 --$mw$
563 -- INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3);
564 -- SELECT 1;
565 --$mw$;
566
567 -- hack implementation
568 -- should be replaced with OmniFind, Contains(), etc
569 CREATE TABLE searchindex (
570 si_page BIGINT NOT NULL,
571 si_title varchar(255) NOT NULL default '',
572 si_text clob NOT NULL
573 );
574
575 -- This table is not used unless profiling is turned on
576 CREATE TABLE profiling (
577 pf_count INTEGER NOT NULL DEFAULT 0,
578 pf_time NUMERIC(18,10) NOT NULL DEFAULT 0,
579 pf_memory NUMERIC(18,10) NOT NULL DEFAULT 0,
580 pf_name VARCHAR(255) NOT NULL,
581 pf_server VARCHAR(255)
582 );
583 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server);
584
585 CREATE TABLE protected_titles (
586 pt_namespace INTEGER NOT NULL,
587 pt_title VARCHAR(255) NOT NULL,
588 pt_user BIGINT NOT NULL DEFAULT 0,
589 -- REFERENCES user(user_id) ON DELETE SET NULL,
590 pt_reason VARCHAR(1024),
591 pt_timestamp TIMESTAMP(3) NOT NULL,
592 pt_expiry TIMESTAMP(3) ,
593 pt_create_perm VARCHAR(60) NOT NULL DEFAULT ''
594 );
595 CREATE UNIQUE INDEX protected_titles_unique ON protected_titles(pt_namespace, pt_title);
596
597
598
599 CREATE TABLE updatelog (
600 ul_key VARCHAR(255) NOT NULL PRIMARY KEY
601 );
602
603
604 CREATE TABLE category (
605 cat_id INTEGER NOT NULL PRIMARY KEY GENERATED BY DEFAULT AS IDENTITY (START WITH 1),
606 --PRIMARY KEY DEFAULT nextval('category_id_seq'),
607 cat_title VARCHAR(255) NOT NULL,
608 cat_pages INTEGER NOT NULL DEFAULT 0,
609 cat_subcats INTEGER NOT NULL DEFAULT 0,
610 cat_files INTEGER NOT NULL DEFAULT 0,
611 cat_hidden SMALLINT NOT NULL DEFAULT 0
612 );
613 CREATE UNIQUE INDEX category_title ON category(cat_title);
614 CREATE INDEX category_pages ON category(cat_pages);
615
616 -- added for 1.15
617
618 -- A table to track tags for revisions, logs and recent changes.
619 CREATE TABLE change_tag (
620 ct_rc_id INTEGER,
621 ct_log_id INTEGER,
622 ct_rev_id INTEGER,
623 ct_tag varchar(255) NOT NULL,
624 ct_params CLOB(64K) INLINE LENGTH 4096
625 );
626 CREATE UNIQUE INDEX change_tag_rc_tag ON change_tag (ct_rc_id,ct_tag);
627 CREATE UNIQUE INDEX change_tag_log_tag ON change_tag (ct_log_id,ct_tag);
628 CREATE UNIQUE INDEX change_tag_rev_tag ON change_tag (ct_rev_id,ct_tag);
629 -- Covering index, so we can pull all the info only out of the index.
630 CREATE INDEX change_tag_tag_id ON change_tag (ct_tag,ct_rc_id,ct_rev_id,ct_log_id);
631
632
633 -- Rollup table to pull a LIST of tags simply
634 CREATE TABLE tag_summary (
635 ts_rc_id INTEGER,
636 ts_log_id INTEGER,
637 ts_rev_id INTEGER,
638 ts_tags CLOB(64K) INLINE LENGTH 4096 NOT NULL
639 );
640 CREATE UNIQUE INDEX tag_summary_rc_id ON tag_summary (ts_rc_id);
641 CREATE UNIQUE INDEX tag_summary_log_id ON tag_summary (ts_log_id);
642 CREATE UNIQUE INDEX tag_summary_rev_id ON tag_summary (ts_rev_id);
643
644
645 CREATE TABLE valid_tag (
646 vt_tag varchar(255) NOT NULL PRIMARY KEY
647 );
648
649 --
650 -- User preferences and perhaps other fun stuff. :)
651 -- Replaces the old user.user_options blob, with a couple nice properties:
652 --
653 -- 1) We only store non-default settings, so changes to the defaults
654 -- are now reflected for everybody, not just new accounts.
655 -- 2) We can more easily do bulk lookups, statistics, or modifications of
656 -- saved options since it's a sane table structure.
657 --
658 CREATE TABLE user_properties (
659 -- Foreign key to user.user_id
660 up_user BIGINT NOT NULL,
661
662 -- Name of the option being saved. This is indexed for bulk lookup.
663 up_property VARCHAR(32) FOR BIT DATA NOT NULL,
664
665 -- Property value as a string.
666 up_value CLOB(64K) INLINE LENGTH 4096
667 );
668 CREATE UNIQUE INDEX user_properties_user_property ON user_properties (up_user,up_property);
669 CREATE INDEX user_properties_property ON user_properties (up_property);
670
671 CREATE TABLE log_search (
672 -- The type of ID (rev ID, log ID, rev TIMESTAMP(3), username)
673 ls_field VARCHAR(32) FOR BIT DATA NOT NULL,
674 -- The value of the ID
675 ls_value varchar(255) NOT NULL,
676 -- Key to log_id
677 ls_log_id BIGINT NOT NULL default 0
678 );
679 CREATE UNIQUE INDEX ls_field_val ON log_search (ls_field,ls_value,ls_log_id);
680 CREATE INDEX ls_log_id ON log_search (ls_log_id);
681
682 -- Table for storing localisation data
683 CREATE TABLE l10n_cache (
684 -- Language code
685 lc_lang VARCHAR(32) NOT NULL,
686 -- Cache key
687 lc_key VARCHAR(255) NOT NULL,
688 -- Value
689 lc_value CLOB(16M) INLINE LENGTH 4096 NOT NULL
690 );
691 CREATE INDEX lc_lang_key ON l10n_cache (lc_lang, lc_key);
692