[ Index ] |
PHP Cross Reference of MediaWiki-1.24.0 |
[Summary view] [Print] [Text view]
1 -- SQL to create the initial tables for the MediaWiki database. 2 -- This is read and executed by the install script; you should 3 -- not have to run it by itself unless doing a manual install. 4 -- This is the PostgreSQL version. 5 -- For information about each table, please see the notes in maintenance/tables.sql 6 -- Please make sure all dollar-quoting uses $mw$ at the start of the line 7 -- TODO: Change CHAR/SMALLINT to BOOL (still used in a non-bool fashion in PHP code) 8 9 BEGIN; 10 SET client_min_messages = 'ERROR'; 11 12 DROP SEQUENCE IF EXISTS user_user_id_seq CASCADE; 13 DROP SEQUENCE IF EXISTS page_page_id_seq CASCADE; 14 DROP SEQUENCE IF EXISTS revision_rev_id_seq CASCADE; 15 DROP SEQUENCE IF EXISTS text_old_id_seq CASCADE; 16 DROP SEQUENCE IF EXISTS page_restrictions_pr_id_seq CASCADE; 17 DROP SEQUENCE IF EXISTS ipblocks_ipb_id_seq CASCADE; 18 DROP SEQUENCE IF EXISTS filearchive_fa_id_seq CASCADE; 19 DROP SEQUENCE IF EXISTS uploadstash_us_id_seq CASCADE; 20 DROP SEQUENCE IF EXISTS recentchanges_rc_id_seq CASCADE; 21 DROP SEQUENCE IF EXISTS logging_log_id_seq CASCADE; 22 DROP SEQUENCE IF EXISTS job_job_id_seq CASCADE; 23 DROP SEQUENCE IF EXISTS category_cat_id_seq CASCADE; 24 DROP SEQUENCE IF EXISTS archive_ar_id_seq CASCADE; 25 DROP SEQUENCE IF EXISTS externallinks_el_id_seq CASCADE; 26 DROP SEQUENCE IF EXISTS sites_site_id_seq CASCADE; 27 DROP FUNCTION IF EXISTS page_deleted() CASCADE; 28 DROP FUNCTION IF EXISTS ts2_page_title() CASCADE; 29 DROP FUNCTION IF EXISTS ts2_page_text() CASCADE; 30 DROP FUNCTION IF EXISTS add_interwiki(TEXT,INT,SMALLINT) CASCADE; 31 DROP TYPE IF EXISTS media_type CASCADE; 32 33 CREATE SEQUENCE user_user_id_seq MINVALUE 0 START WITH 0; 34 CREATE TABLE mwuser ( -- replace reserved word 'user' 35 user_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('user_user_id_seq'), 36 user_name TEXT NOT NULL UNIQUE, 37 user_real_name TEXT, 38 user_password TEXT, 39 user_newpassword TEXT, 40 user_newpass_time TIMESTAMPTZ, 41 user_token TEXT, 42 user_email TEXT, 43 user_email_token TEXT, 44 user_email_token_expires TIMESTAMPTZ, 45 user_email_authenticated TIMESTAMPTZ, 46 user_touched TIMESTAMPTZ, 47 user_registration TIMESTAMPTZ, 48 user_editcount INTEGER, 49 user_password_expires TIMESTAMPTZ NULL 50 ); 51 CREATE INDEX user_email_token_idx ON mwuser (user_email_token); 52 53 -- Create a dummy user to satisfy fk contraints especially with revisions 54 INSERT INTO mwuser 55 VALUES (DEFAULT,'Anonymous','',NULL,NULL,NULL,NULL,NULL,NULL,NULL,NULL,now(),now()); 56 57 CREATE TABLE user_groups ( 58 ug_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, 59 ug_group TEXT NOT NULL 60 ); 61 CREATE UNIQUE INDEX user_groups_unique ON user_groups (ug_user, ug_group); 62 63 CREATE TABLE user_former_groups ( 64 ufg_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, 65 ufg_group TEXT NOT NULL 66 ); 67 CREATE UNIQUE INDEX ufg_user_group ON user_former_groups (ufg_user, ufg_group); 68 69 CREATE TABLE user_newtalk ( 70 user_id INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, 71 user_ip TEXT NULL, 72 user_last_timestamp TIMESTAMPTZ 73 ); 74 CREATE INDEX user_newtalk_id_idx ON user_newtalk (user_id); 75 CREATE INDEX user_newtalk_ip_idx ON user_newtalk (user_ip); 76 77 78 CREATE SEQUENCE page_page_id_seq; 79 CREATE TABLE page ( 80 page_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('page_page_id_seq'), 81 page_namespace SMALLINT NOT NULL, 82 page_title TEXT NOT NULL, 83 page_restrictions TEXT, 84 page_counter BIGINT NOT NULL DEFAULT 0, 85 page_is_redirect SMALLINT NOT NULL DEFAULT 0, 86 page_is_new SMALLINT NOT NULL DEFAULT 0, 87 page_random NUMERIC(15,14) NOT NULL DEFAULT RANDOM(), 88 page_touched TIMESTAMPTZ, 89 page_links_updated TIMESTAMPTZ NULL, 90 page_latest INTEGER NOT NULL, -- FK? 91 page_len INTEGER NOT NULL, 92 page_content_model TEXT, 93 page_lang TEXT DEFAULT NULL 94 ); 95 CREATE UNIQUE INDEX page_unique_name ON page (page_namespace, page_title); 96 CREATE INDEX page_main_title ON page (page_title text_pattern_ops) WHERE page_namespace = 0; 97 CREATE INDEX page_talk_title ON page (page_title text_pattern_ops) WHERE page_namespace = 1; 98 CREATE INDEX page_user_title ON page (page_title text_pattern_ops) WHERE page_namespace = 2; 99 CREATE INDEX page_utalk_title ON page (page_title text_pattern_ops) WHERE page_namespace = 3; 100 CREATE INDEX page_project_title ON page (page_title text_pattern_ops) WHERE page_namespace = 4; 101 CREATE INDEX page_mediawiki_title ON page (page_title text_pattern_ops) WHERE page_namespace = 8; 102 CREATE INDEX page_random_idx ON page (page_random); 103 CREATE INDEX page_len_idx ON page (page_len); 104 105 CREATE FUNCTION page_deleted() RETURNS TRIGGER LANGUAGE plpgsql AS 106 $mw$ 107 BEGIN 108 DELETE FROM recentchanges WHERE rc_namespace = OLD.page_namespace AND rc_title = OLD.page_title; 109 RETURN NULL; 110 END; 111 $mw$; 112 113 CREATE TRIGGER page_deleted AFTER DELETE ON page 114 FOR EACH ROW EXECUTE PROCEDURE page_deleted(); 115 116 CREATE SEQUENCE revision_rev_id_seq; 117 CREATE TABLE revision ( 118 rev_id INTEGER NOT NULL UNIQUE DEFAULT nextval('revision_rev_id_seq'), 119 rev_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, 120 rev_text_id INTEGER NULL, -- FK 121 rev_comment TEXT, 122 rev_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE RESTRICT DEFERRABLE INITIALLY DEFERRED, 123 rev_user_text TEXT NOT NULL, 124 rev_timestamp TIMESTAMPTZ NOT NULL, 125 rev_minor_edit SMALLINT NOT NULL DEFAULT 0, 126 rev_deleted SMALLINT NOT NULL DEFAULT 0, 127 rev_len INTEGER NULL, 128 rev_parent_id INTEGER NULL, 129 rev_sha1 TEXT NOT NULL DEFAULT '', 130 rev_content_model TEXT, 131 rev_content_format TEXT 132 ); 133 CREATE UNIQUE INDEX revision_unique ON revision (rev_page, rev_id); 134 CREATE INDEX rev_text_id_idx ON revision (rev_text_id); 135 CREATE INDEX rev_timestamp_idx ON revision (rev_timestamp); 136 CREATE INDEX rev_user_idx ON revision (rev_user); 137 CREATE INDEX rev_user_text_idx ON revision (rev_user_text); 138 139 140 CREATE SEQUENCE text_old_id_seq; 141 CREATE TABLE pagecontent ( -- replaces reserved word 'text' 142 old_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('text_old_id_seq'), 143 old_text TEXT, 144 old_flags TEXT 145 ); 146 147 148 CREATE SEQUENCE page_restrictions_pr_id_seq; 149 CREATE TABLE page_restrictions ( 150 pr_id INTEGER NOT NULL UNIQUE DEFAULT nextval('page_restrictions_pr_id_seq'), 151 pr_page INTEGER NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, 152 pr_type TEXT NOT NULL, 153 pr_level TEXT NOT NULL, 154 pr_cascade SMALLINT NOT NULL, 155 pr_user INTEGER NULL, 156 pr_expiry TIMESTAMPTZ NULL 157 ); 158 ALTER TABLE page_restrictions ADD CONSTRAINT page_restrictions_pk PRIMARY KEY (pr_page,pr_type); 159 160 CREATE TABLE page_props ( 161 pp_page INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, 162 pp_propname TEXT NOT NULL, 163 pp_value TEXT NOT NULL, 164 pp_sortkey FLOAT 165 ); 166 ALTER TABLE page_props ADD CONSTRAINT page_props_pk PRIMARY KEY (pp_page,pp_propname); 167 CREATE INDEX page_props_propname ON page_props (pp_propname); 168 CREATE UNIQUE INDEX pp_propname_page ON page_props (pp_propname,pp_page); 169 CREATE INDEX pp_propname_sortkey_page ON page_props (pp_propname, pp_sortkey, pp_page) WHERE (pp_sortkey IS NOT NULL); 170 171 CREATE SEQUENCE archive_ar_id_seq; 172 CREATE TABLE archive ( 173 ar_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('archive_ar_id_seq'), 174 ar_namespace SMALLINT NOT NULL, 175 ar_title TEXT NOT NULL, 176 ar_text TEXT, -- technically should be bytea, but not used anymore 177 ar_page_id INTEGER NULL, 178 ar_parent_id INTEGER NULL, 179 ar_sha1 TEXT NOT NULL DEFAULT '', 180 ar_comment TEXT, 181 ar_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED, 182 ar_user_text TEXT NOT NULL, 183 ar_timestamp TIMESTAMPTZ NOT NULL, 184 ar_minor_edit SMALLINT NOT NULL DEFAULT 0, 185 ar_flags TEXT, 186 ar_rev_id INTEGER, 187 ar_text_id INTEGER, 188 ar_deleted SMALLINT NOT NULL DEFAULT 0, 189 ar_len INTEGER NULL, 190 ar_content_model TEXT, 191 ar_content_format TEXT 192 ); 193 CREATE INDEX archive_name_title_timestamp ON archive (ar_namespace,ar_title,ar_timestamp); 194 CREATE INDEX archive_user_text ON archive (ar_user_text); 195 196 197 CREATE TABLE redirect ( 198 rd_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, 199 rd_namespace SMALLINT NOT NULL, 200 rd_title TEXT NOT NULL, 201 rd_interwiki TEXT NULL, 202 rd_fragment TEXT NULL 203 ); 204 CREATE INDEX redirect_ns_title ON redirect (rd_namespace,rd_title,rd_from); 205 206 207 CREATE TABLE pagelinks ( 208 pl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, 209 pl_from_namespace INTEGER NOT NULL DEFAULT 0, 210 pl_namespace SMALLINT NOT NULL, 211 pl_title TEXT NOT NULL 212 ); 213 CREATE UNIQUE INDEX pagelink_unique ON pagelinks (pl_from,pl_namespace,pl_title); 214 CREATE INDEX pagelinks_title ON pagelinks (pl_title); 215 216 CREATE TABLE templatelinks ( 217 tl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, 218 tl_from_namespace INTEGER NOT NULL DEFAULT 0, 219 tl_namespace SMALLINT NOT NULL, 220 tl_title TEXT NOT NULL 221 ); 222 CREATE UNIQUE INDEX templatelinks_unique ON templatelinks (tl_namespace,tl_title,tl_from); 223 CREATE INDEX templatelinks_from ON templatelinks (tl_from); 224 225 CREATE TABLE imagelinks ( 226 il_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, 227 il_from_namespace INTEGER NOT NULL DEFAULT 0, 228 il_to TEXT NOT NULL 229 ); 230 CREATE UNIQUE INDEX il_from ON imagelinks (il_to,il_from); 231 232 CREATE TABLE categorylinks ( 233 cl_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, 234 cl_to TEXT NOT NULL, 235 cl_sortkey TEXT NULL, 236 cl_timestamp TIMESTAMPTZ NOT NULL, 237 cl_sortkey_prefix TEXT NOT NULL DEFAULT '', 238 cl_collation TEXT NOT NULL DEFAULT 0, 239 cl_type TEXT NOT NULL DEFAULT 'page' 240 ); 241 CREATE UNIQUE INDEX cl_from ON categorylinks (cl_from, cl_to); 242 CREATE INDEX cl_sortkey ON categorylinks (cl_to, cl_sortkey, cl_from); 243 244 CREATE SEQUENCE externallinks_el_id_seq; 245 CREATE TABLE externallinks ( 246 el_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('externallinks_el_id_seq'), 247 el_from INTEGER NOT NULL REFERENCES page(page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, 248 el_to TEXT NOT NULL, 249 el_index TEXT NOT NULL 250 ); 251 CREATE INDEX externallinks_from_to ON externallinks (el_from,el_to); 252 CREATE INDEX externallinks_index ON externallinks (el_index); 253 254 CREATE TABLE langlinks ( 255 ll_from INTEGER NOT NULL REFERENCES page (page_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, 256 ll_lang TEXT, 257 ll_title TEXT 258 ); 259 CREATE UNIQUE INDEX langlinks_unique ON langlinks (ll_from,ll_lang); 260 CREATE INDEX langlinks_lang_title ON langlinks (ll_lang,ll_title); 261 262 263 CREATE TABLE site_stats ( 264 ss_row_id INTEGER NOT NULL UNIQUE, 265 ss_total_views INTEGER DEFAULT 0, 266 ss_total_edits INTEGER DEFAULT 0, 267 ss_good_articles INTEGER DEFAULT 0, 268 ss_total_pages INTEGER DEFAULT -1, 269 ss_users INTEGER DEFAULT -1, 270 ss_active_users INTEGER DEFAULT -1, 271 ss_admins INTEGER DEFAULT -1, 272 ss_images INTEGER DEFAULT 0 273 ); 274 275 CREATE TABLE hitcounter ( 276 hc_id BIGINT NOT NULL 277 ); 278 279 280 CREATE SEQUENCE ipblocks_ipb_id_seq; 281 CREATE TABLE ipblocks ( 282 ipb_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('ipblocks_ipb_id_seq'), 283 ipb_address TEXT NULL, 284 ipb_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED, 285 ipb_by INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, 286 ipb_by_text TEXT NOT NULL DEFAULT '', 287 ipb_reason TEXT NOT NULL, 288 ipb_timestamp TIMESTAMPTZ NOT NULL, 289 ipb_auto SMALLINT NOT NULL DEFAULT 0, 290 ipb_anon_only SMALLINT NOT NULL DEFAULT 0, 291 ipb_create_account SMALLINT NOT NULL DEFAULT 1, 292 ipb_enable_autoblock SMALLINT NOT NULL DEFAULT 1, 293 ipb_expiry TIMESTAMPTZ NOT NULL, 294 ipb_range_start TEXT, 295 ipb_range_end TEXT, 296 ipb_deleted SMALLINT NOT NULL DEFAULT 0, 297 ipb_block_email SMALLINT NOT NULL DEFAULT 0, 298 ipb_allow_usertalk SMALLINT NOT NULL DEFAULT 0, 299 ipb_parent_block_id INTEGER NULL REFERENCES ipblocks(ipb_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED 300 301 ); 302 CREATE UNIQUE INDEX ipb_address_unique ON ipblocks (ipb_address,ipb_user,ipb_auto,ipb_anon_only); 303 CREATE INDEX ipb_user ON ipblocks (ipb_user); 304 CREATE INDEX ipb_range ON ipblocks (ipb_range_start,ipb_range_end); 305 CREATE INDEX ipb_parent_block_id ON ipblocks (ipb_parent_block_id); 306 307 308 CREATE TABLE image ( 309 img_name TEXT NOT NULL PRIMARY KEY, 310 img_size INTEGER NOT NULL, 311 img_width INTEGER NOT NULL, 312 img_height INTEGER NOT NULL, 313 img_metadata BYTEA NOT NULL DEFAULT '', 314 img_bits SMALLINT, 315 img_media_type TEXT, 316 img_major_mime TEXT DEFAULT 'unknown', 317 img_minor_mime TEXT DEFAULT 'unknown', 318 img_description TEXT NOT NULL, 319 img_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED, 320 img_user_text TEXT NOT NULL, 321 img_timestamp TIMESTAMPTZ, 322 img_sha1 TEXT NOT NULL DEFAULT '' 323 ); 324 CREATE INDEX img_size_idx ON image (img_size); 325 CREATE INDEX img_timestamp_idx ON image (img_timestamp); 326 CREATE INDEX img_sha1 ON image (img_sha1); 327 328 CREATE TABLE oldimage ( 329 oi_name TEXT NOT NULL, 330 oi_archive_name TEXT NOT NULL, 331 oi_size INTEGER NOT NULL, 332 oi_width INTEGER NOT NULL, 333 oi_height INTEGER NOT NULL, 334 oi_bits SMALLINT NULL, 335 oi_description TEXT, 336 oi_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED, 337 oi_user_text TEXT NOT NULL, 338 oi_timestamp TIMESTAMPTZ NULL, 339 oi_metadata BYTEA NOT NULL DEFAULT '', 340 oi_media_type TEXT NULL, 341 oi_major_mime TEXT NULL DEFAULT 'unknown', 342 oi_minor_mime TEXT NULL DEFAULT 'unknown', 343 oi_deleted SMALLINT NOT NULL DEFAULT 0, 344 oi_sha1 TEXT NOT NULL DEFAULT '' 345 ); 346 ALTER TABLE oldimage ADD CONSTRAINT oldimage_oi_name_fkey_cascaded FOREIGN KEY (oi_name) REFERENCES image(img_name) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED; 347 CREATE INDEX oi_name_timestamp ON oldimage (oi_name,oi_timestamp); 348 CREATE INDEX oi_name_archive_name ON oldimage (oi_name,oi_archive_name); 349 CREATE INDEX oi_sha1 ON oldimage (oi_sha1); 350 351 352 CREATE SEQUENCE filearchive_fa_id_seq; 353 CREATE TABLE filearchive ( 354 fa_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('filearchive_fa_id_seq'), 355 fa_name TEXT NOT NULL, 356 fa_archive_name TEXT, 357 fa_storage_group TEXT, 358 fa_storage_key TEXT, 359 fa_deleted_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED, 360 fa_deleted_timestamp TIMESTAMPTZ NOT NULL, 361 fa_deleted_reason TEXT, 362 fa_size INTEGER NOT NULL, 363 fa_width INTEGER NOT NULL, 364 fa_height INTEGER NOT NULL, 365 fa_metadata BYTEA NOT NULL DEFAULT '', 366 fa_bits SMALLINT, 367 fa_media_type TEXT, 368 fa_major_mime TEXT DEFAULT 'unknown', 369 fa_minor_mime TEXT DEFAULT 'unknown', 370 fa_description TEXT NOT NULL, 371 fa_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED, 372 fa_user_text TEXT NOT NULL, 373 fa_timestamp TIMESTAMPTZ, 374 fa_deleted SMALLINT NOT NULL DEFAULT 0, 375 fa_sha1 TEXT NOT NULL DEFAULT '' 376 ); 377 CREATE INDEX fa_name_time ON filearchive (fa_name, fa_timestamp); 378 CREATE INDEX fa_dupe ON filearchive (fa_storage_group, fa_storage_key); 379 CREATE INDEX fa_notime ON filearchive (fa_deleted_timestamp); 380 CREATE INDEX fa_nouser ON filearchive (fa_deleted_user); 381 CREATE INDEX fa_sha1 ON filearchive (fa_sha1); 382 383 CREATE SEQUENCE uploadstash_us_id_seq; 384 CREATE TYPE media_type AS ENUM ('UNKNOWN','BITMAP','DRAWING','AUDIO','VIDEO','MULTIMEDIA','OFFICE','TEXT','EXECUTABLE','ARCHIVE'); 385 386 CREATE TABLE uploadstash ( 387 us_id INTEGER PRIMARY KEY NOT NULL DEFAULT nextval('uploadstash_us_id_seq'), 388 us_user INTEGER, 389 us_key TEXT, 390 us_orig_path TEXT, 391 us_path TEXT, 392 us_props BYTEA, 393 us_source_type TEXT, 394 us_timestamp TIMESTAMPTZ, 395 us_status TEXT, 396 us_chunk_inx INTEGER NULL, 397 us_size INTEGER, 398 us_sha1 TEXT, 399 us_mime TEXT, 400 us_media_type media_type DEFAULT NULL, 401 us_image_width INTEGER, 402 us_image_height INTEGER, 403 us_image_bits SMALLINT 404 ); 405 406 CREATE INDEX us_user_idx ON uploadstash (us_user); 407 CREATE UNIQUE INDEX us_key_idx ON uploadstash (us_key); 408 CREATE INDEX us_timestamp_idx ON uploadstash (us_timestamp); 409 410 411 CREATE SEQUENCE recentchanges_rc_id_seq; 412 CREATE TABLE recentchanges ( 413 rc_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('recentchanges_rc_id_seq'), 414 rc_timestamp TIMESTAMPTZ NOT NULL, 415 rc_cur_time TIMESTAMPTZ NULL, 416 rc_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED, 417 rc_user_text TEXT NOT NULL, 418 rc_namespace SMALLINT NOT NULL, 419 rc_title TEXT NOT NULL, 420 rc_comment TEXT, 421 rc_minor SMALLINT NOT NULL DEFAULT 0, 422 rc_bot SMALLINT NOT NULL DEFAULT 0, 423 rc_new SMALLINT NOT NULL DEFAULT 0, 424 rc_cur_id INTEGER NULL REFERENCES page(page_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED, 425 rc_this_oldid INTEGER NOT NULL, 426 rc_last_oldid INTEGER NOT NULL, 427 rc_type SMALLINT NOT NULL DEFAULT 0, 428 rc_source TEXT NOT NULL, 429 rc_patrolled SMALLINT NOT NULL DEFAULT 0, 430 rc_ip CIDR, 431 rc_old_len INTEGER, 432 rc_new_len INTEGER, 433 rc_deleted SMALLINT NOT NULL DEFAULT 0, 434 rc_logid INTEGER NOT NULL DEFAULT 0, 435 rc_log_type TEXT, 436 rc_log_action TEXT, 437 rc_params TEXT 438 ); 439 CREATE INDEX rc_timestamp ON recentchanges (rc_timestamp); 440 CREATE INDEX rc_timestamp_bot ON recentchanges (rc_timestamp) WHERE rc_bot = 0; 441 CREATE INDEX rc_namespace_title ON recentchanges (rc_namespace, rc_title); 442 CREATE INDEX rc_cur_id ON recentchanges (rc_cur_id); 443 CREATE INDEX new_name_timestamp ON recentchanges (rc_new, rc_namespace, rc_timestamp); 444 CREATE INDEX rc_ip ON recentchanges (rc_ip); 445 446 447 CREATE TABLE watchlist ( 448 wl_user INTEGER NOT NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, 449 wl_namespace SMALLINT NOT NULL DEFAULT 0, 450 wl_title TEXT NOT NULL, 451 wl_notificationtimestamp TIMESTAMPTZ 452 ); 453 CREATE UNIQUE INDEX wl_user_namespace_title ON watchlist (wl_namespace, wl_title, wl_user); 454 CREATE INDEX wl_user ON watchlist (wl_user); 455 CREATE INDEX wl_user_notificationtimestamp ON watchlist (wl_user, wl_notificationtimestamp); 456 457 458 CREATE TABLE interwiki ( 459 iw_prefix TEXT NOT NULL UNIQUE, 460 iw_url TEXT NOT NULL, 461 iw_local SMALLINT NOT NULL, 462 iw_trans SMALLINT NOT NULL DEFAULT 0, 463 iw_api TEXT NOT NULL DEFAULT '', 464 iw_wikiid TEXT NOT NULL DEFAULT '' 465 ); 466 467 468 CREATE TABLE querycache ( 469 qc_type TEXT NOT NULL, 470 qc_value INTEGER NOT NULL, 471 qc_namespace SMALLINT NOT NULL, 472 qc_title TEXT NOT NULL 473 ); 474 CREATE INDEX querycache_type_value ON querycache (qc_type, qc_value); 475 476 CREATE TABLE querycache_info ( 477 qci_type TEXT UNIQUE, 478 qci_timestamp TIMESTAMPTZ NULL 479 ); 480 481 CREATE TABLE querycachetwo ( 482 qcc_type TEXT NOT NULL, 483 qcc_value INTEGER NOT NULL DEFAULT 0, 484 qcc_namespace INTEGER NOT NULL DEFAULT 0, 485 qcc_title TEXT NOT NULL DEFAULT '', 486 qcc_namespacetwo INTEGER NOT NULL DEFAULT 0, 487 qcc_titletwo TEXT 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 TEXT UNIQUE, 495 value BYTEA NOT NULL DEFAULT '', 496 exptime TIMESTAMPTZ NOT NULL 497 ); 498 CREATE INDEX objectcacache_exptime ON objectcache (exptime); 499 500 CREATE TABLE transcache ( 501 tc_url TEXT NOT NULL UNIQUE, 502 tc_contents TEXT NOT NULL, 503 tc_time TIMESTAMPTZ NOT NULL 504 ); 505 506 507 CREATE SEQUENCE logging_log_id_seq; 508 CREATE TABLE logging ( 509 log_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('logging_log_id_seq'), 510 log_type TEXT NOT NULL, 511 log_action TEXT NOT NULL, 512 log_timestamp TIMESTAMPTZ NOT NULL, 513 log_user INTEGER REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED, 514 log_namespace SMALLINT NOT NULL, 515 log_title TEXT NOT NULL, 516 log_comment TEXT, 517 log_params TEXT, 518 log_deleted SMALLINT NOT NULL DEFAULT 0, 519 log_user_text TEXT NOT NULL DEFAULT '', 520 log_page INTEGER 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 logging_times ON logging (log_timestamp); 526 CREATE INDEX logging_user_type_time ON logging (log_user, log_type, log_timestamp); 527 CREATE INDEX logging_page_id_time ON logging (log_page, log_timestamp); 528 CREATE INDEX logging_user_text_type_time ON logging (log_user_text, log_type, log_timestamp); 529 CREATE INDEX logging_user_text_time ON logging (log_user_text, log_timestamp); 530 531 CREATE TABLE log_search ( 532 ls_field TEXT NOT NULL, 533 ls_value TEXT NOT NULL, 534 ls_log_id INTEGER NOT NULL DEFAULT 0, 535 PRIMARY KEY (ls_field,ls_value,ls_log_id) 536 ); 537 CREATE INDEX ls_log_id ON log_search (ls_log_id); 538 539 540 CREATE SEQUENCE job_job_id_seq; 541 CREATE TABLE job ( 542 job_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('job_job_id_seq'), 543 job_cmd TEXT NOT NULL, 544 job_namespace SMALLINT NOT NULL, 545 job_title TEXT NOT NULL, 546 job_timestamp TIMESTAMPTZ, 547 job_params TEXT NOT NULL, 548 job_random INTEGER NOT NULL DEFAULT 0, 549 job_attempts INTEGER NOT NULL DEFAULT 0, 550 job_token TEXT NOT NULL DEFAULT '', 551 job_token_timestamp TIMESTAMPTZ, 552 job_sha1 TEXT NOT NULL DEFAULT '' 553 ); 554 CREATE INDEX job_sha1 ON job (job_sha1); 555 CREATE INDEX job_cmd_token ON job (job_cmd, job_token, job_random); 556 CREATE INDEX job_cmd_token_id ON job (job_cmd, job_token, job_id); 557 CREATE INDEX job_cmd_namespace_title ON job (job_cmd, job_namespace, job_title); 558 CREATE INDEX job_timestamp_idx ON job (job_timestamp); 559 560 -- Tsearch2 2 stuff. Will fail if we don't have proper access to the tsearch2 tables 561 -- Version 8.3 or higher only. Previous versions would need another parmeter for to_tsvector. 562 -- Make sure you also change patch-tsearch2funcs.sql if the funcs below change. 563 564 ALTER TABLE page ADD titlevector tsvector; 565 CREATE FUNCTION ts2_page_title() RETURNS TRIGGER LANGUAGE plpgsql AS 566 $mw$ 567 BEGIN 568 IF TG_OP = 'INSERT' THEN 569 NEW.titlevector = to_tsvector(REPLACE(NEW.page_title,'/',' ')); 570 ELSIF NEW.page_title != OLD.page_title THEN 571 NEW.titlevector := to_tsvector(REPLACE(NEW.page_title,'/',' ')); 572 END IF; 573 RETURN NEW; 574 END; 575 $mw$; 576 577 CREATE TRIGGER ts2_page_title BEFORE INSERT OR UPDATE ON page 578 FOR EACH ROW EXECUTE PROCEDURE ts2_page_title(); 579 580 581 ALTER TABLE pagecontent ADD textvector tsvector; 582 CREATE FUNCTION ts2_page_text() RETURNS TRIGGER LANGUAGE plpgsql AS 583 $mw$ 584 BEGIN 585 IF TG_OP = 'INSERT' THEN 586 NEW.textvector = to_tsvector(NEW.old_text); 587 ELSIF NEW.old_text != OLD.old_text THEN 588 NEW.textvector := to_tsvector(NEW.old_text); 589 END IF; 590 RETURN NEW; 591 END; 592 $mw$; 593 594 CREATE TRIGGER ts2_page_text BEFORE INSERT OR UPDATE ON pagecontent 595 FOR EACH ROW EXECUTE PROCEDURE ts2_page_text(); 596 597 -- These are added by the setup script due to version compatibility issues 598 -- If using 8.1, we switch from "gin" to "gist" 599 600 CREATE INDEX ts2_page_title ON page USING gin(titlevector); 601 CREATE INDEX ts2_page_text ON pagecontent USING gin(textvector); 602 603 CREATE FUNCTION add_interwiki (TEXT,INT,SMALLINT) RETURNS INT LANGUAGE SQL AS 604 $mw$ 605 INSERT INTO interwiki (iw_prefix, iw_url, iw_local) VALUES ($1,$2,$3); 606 SELECT 1; 607 $mw$; 608 609 -- This table is not used unless profiling is turned on 610 CREATE TABLE profiling ( 611 pf_count INTEGER NOT NULL DEFAULT 0, 612 pf_time FLOAT NOT NULL DEFAULT 0, 613 pf_memory FLOAT NOT NULL DEFAULT 0, 614 pf_name TEXT NOT NULL, 615 pf_server TEXT NULL 616 ); 617 CREATE UNIQUE INDEX pf_name_server ON profiling (pf_name, pf_server); 618 619 CREATE TABLE protected_titles ( 620 pt_namespace SMALLINT NOT NULL, 621 pt_title TEXT NOT NULL, 622 pt_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED, 623 pt_reason TEXT NULL, 624 pt_timestamp TIMESTAMPTZ NOT NULL, 625 pt_expiry TIMESTAMPTZ NULL, 626 pt_create_perm TEXT NOT NULL DEFAULT '' 627 ); 628 CREATE UNIQUE INDEX protected_titles_unique ON protected_titles(pt_namespace, pt_title); 629 630 631 CREATE TABLE updatelog ( 632 ul_key TEXT NOT NULL PRIMARY KEY, 633 ul_value TEXT 634 ); 635 636 637 CREATE SEQUENCE category_cat_id_seq; 638 CREATE TABLE category ( 639 cat_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('category_cat_id_seq'), 640 cat_title TEXT NOT NULL, 641 cat_pages INTEGER NOT NULL DEFAULT 0, 642 cat_subcats INTEGER NOT NULL DEFAULT 0, 643 cat_files INTEGER NOT NULL DEFAULT 0, 644 cat_hidden SMALLINT NOT NULL DEFAULT 0 645 ); 646 CREATE UNIQUE INDEX category_title ON category(cat_title); 647 CREATE INDEX category_pages ON category(cat_pages); 648 649 CREATE TABLE change_tag ( 650 ct_rc_id INTEGER NULL, 651 ct_log_id INTEGER NULL, 652 ct_rev_id INTEGER NULL, 653 ct_tag TEXT NOT NULL, 654 ct_params TEXT NULL 655 ); 656 CREATE UNIQUE INDEX change_tag_rc_tag ON change_tag(ct_rc_id,ct_tag); 657 CREATE UNIQUE INDEX change_tag_log_tag ON change_tag(ct_log_id,ct_tag); 658 CREATE UNIQUE INDEX change_tag_rev_tag ON change_tag(ct_rev_id,ct_tag); 659 CREATE INDEX change_tag_tag_id ON change_tag(ct_tag,ct_rc_id,ct_rev_id,ct_log_id); 660 661 CREATE TABLE tag_summary ( 662 ts_rc_id INTEGER NULL, 663 ts_log_id INTEGER NULL, 664 ts_rev_id INTEGER NULL, 665 ts_tags TEXT NOT NULL 666 ); 667 CREATE UNIQUE INDEX tag_summary_rc_id ON tag_summary(ts_rc_id); 668 CREATE UNIQUE INDEX tag_summary_log_id ON tag_summary(ts_log_id); 669 CREATE UNIQUE INDEX tag_summary_rev_id ON tag_summary(ts_rev_id); 670 671 CREATE TABLE valid_tag ( 672 vt_tag TEXT NOT NULL PRIMARY KEY 673 ); 674 675 CREATE TABLE user_properties ( 676 up_user INTEGER NULL REFERENCES mwuser(user_id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, 677 up_property TEXT NOT NULL, 678 up_value TEXT 679 ); 680 CREATE UNIQUE INDEX user_properties_user_property ON user_properties (up_user,up_property); 681 CREATE INDEX user_properties_property ON user_properties (up_property); 682 683 CREATE TABLE l10n_cache ( 684 lc_lang TEXT NOT NULL, 685 lc_key TEXT NOT NULL, 686 lc_value BYTEA NOT NULL 687 ); 688 CREATE INDEX l10n_cache_lc_lang_key ON l10n_cache (lc_lang, lc_key); 689 690 CREATE TABLE iwlinks ( 691 iwl_from INTEGER NOT NULL DEFAULT 0, 692 iwl_prefix TEXT NOT NULL DEFAULT '', 693 iwl_title TEXT NOT NULL DEFAULT '' 694 ); 695 CREATE UNIQUE INDEX iwl_from ON iwlinks (iwl_from, iwl_prefix, iwl_title); 696 CREATE UNIQUE INDEX iwl_prefix_title_from ON iwlinks (iwl_prefix, iwl_title, iwl_from); 697 CREATE UNIQUE INDEX iwl_prefix_from_title ON iwlinks (iwl_prefix, iwl_from, iwl_title); 698 699 CREATE TABLE msg_resource ( 700 mr_resource TEXT NOT NULL, 701 mr_lang TEXT NOT NULL, 702 mr_blob TEXT NOT NULL, 703 mr_timestamp TIMESTAMPTZ NOT NULL 704 ); 705 CREATE UNIQUE INDEX mr_resource_lang ON msg_resource (mr_resource, mr_lang); 706 707 CREATE TABLE msg_resource_links ( 708 mrl_resource TEXT NOT NULL, 709 mrl_message TEXT NOT NULL 710 ); 711 CREATE UNIQUE INDEX mrl_message_resource ON msg_resource_links (mrl_message, mrl_resource); 712 713 CREATE TABLE module_deps ( 714 md_module TEXT NOT NULL, 715 md_skin TEXT NOT NULL, 716 md_deps TEXT NOT NULL 717 ); 718 CREATE UNIQUE INDEX md_module_skin ON module_deps (md_module, md_skin); 719 720 CREATE SEQUENCE sites_site_id_seq; 721 CREATE TABLE sites ( 722 site_id INTEGER NOT NULL PRIMARY KEY DEFAULT nextval('sites_site_id_seq'), 723 site_global_key TEXT NOT NULL, 724 site_type TEXT NOT NULL, 725 site_group TEXT NOT NULL, 726 site_source TEXT NOT NULL, 727 site_language TEXT NOT NULL, 728 site_protocol TEXT NOT NULL, 729 site_domain TEXT NOT NULL, 730 site_data TEXT NOT NULL, 731 site_forward SMALLINT NOT NULL, 732 site_config TEXT NOT NULL 733 ); 734 CREATE UNIQUE INDEX site_global_key ON sites (site_global_key); 735 CREATE INDEX site_type ON sites (site_type); 736 CREATE INDEX site_group ON sites (site_group); 737 CREATE INDEX site_source ON sites (site_source); 738 CREATE INDEX site_language ON sites (site_language); 739 CREATE INDEX site_protocol ON sites (site_protocol); 740 CREATE INDEX site_domain ON sites (site_domain); 741 CREATE INDEX site_forward ON sites (site_forward); 742 743 CREATE TABLE site_identifiers ( 744 si_site INTEGER NOT NULL, 745 si_type TEXT NOT NULL, 746 si_key TEXT NOT NULL 747 ); 748 CREATE UNIQUE INDEX si_type_key ON site_identifiers (si_type, si_key); 749 CREATE INDEX si_site ON site_identifiers (si_site); 750 CREATE INDEX si_key ON site_identifiers (si_key);
title
Description
Body
title
Description
Body
title
Description
Body
title
Body
Generated: Fri Nov 28 14:03:12 2014 | Cross-referenced by PHPXref 0.7.1 |